You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Copy file name to clipboardexpand all lines: sql/TSqlChatGPT.sql
+288-41
Original file line number
Diff line number
Diff line change
@@ -1,45 +1,70 @@
1
-
--/
2
-
--/ Product: TSqlChatGPT
3
-
--/ Description: Call ChatGPT from Azure SQL Database, and describe objects within the database
4
-
--/
5
-
--/ Author: Adam Buckley, Microsoft
6
-
--/ Creation Date: March 2023
7
-
--/
8
-
--/ Revision History: 1.4 (Error handling improved, and no longer need to find/replace APIM URL)
9
-
--/
10
-
--/
11
-
--/ DISCLAIMER:
12
-
--/ THIS SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A
13
-
--/ PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT,
14
-
--/ TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
15
-
--/
16
-
--/ IMPORTANT: This will currently only work on Azure SQL Database (not on SQL Server or Azure SQL Managed Instance)
17
-
--/
18
-
--/ Provide your API key for OpenAI service (this is for OpenAI, not Azure OpenAI service)
19
-
--/ And also the subscription key for the Azure API Manager API
20
-
--/ The APIM URL Paramater needs to match the API Manager Service URL (e.g. https://myapimanagerresourcename.azure-api.net)
21
-
--/
22
-
--/ Usage Examples:
23
-
--/
24
-
--/ EXEC [dbo].[usp_AskChatGPT] 'Generate a CREATE TABLE script for Customer data';
25
-
--/ EXEC [dbo].[usp_AskChatGPT] 'Generate a SQL function to calculate how many days until a specified date';
26
-
--/ EXEC [dbo].[usp_AskChatGPT] 'Explain this code: SELECT DATEDIFF(DAY,GETDATE(),DATEFROMPARTS(2023,12,25))';
-- Description: Call ChatGPT from Azure SQL Database, and describe objects within the database
4
+
--
5
+
-- Author: Adam Buckley, Microsoft
6
+
-- Creation Date: March 2023
7
+
--
8
+
-- Revision History: 1.1 (Error handling improved, and no longer need to find/replace APIM URL)
9
+
-- 1.2 (AWB, 17/08/2023) - Added natural query language support with the usp_ExecuteNaturalQuery stored procedure
10
+
--
11
+
--
12
+
-- DISCLAIMER:
13
+
-- THIS SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A
14
+
-- PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT,
15
+
-- TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
16
+
--
17
+
-- IMPORTANT: This will currently only work on Azure SQL Database (not on SQL Server or Azure SQL Managed Instance)
18
+
--
19
+
-- Provide your API key for OpenAI service (this is for OpenAI, not Azure OpenAI service)
20
+
-- And also the subscription key for the Azure API Manager API
21
+
-- The APIM URL Paramater needs to match the API Manager Service URL (e.g. https://myapimanagerresourcename.azure-api.net)
22
+
--
23
+
-- Usage Examples:
24
+
--
25
+
-- EXEC [dbo].[usp_AskChatGPT] 'Generate a CREATE TABLE script for Customer data';
26
+
-- EXEC [dbo].[usp_AskChatGPT] 'Generate a SQL function to calculate how many days until a specified date';
27
+
-- EXEC [dbo].[usp_AskChatGPT] 'Explain this code: SELECT DATEDIFF(DAY,GETDATE(),DATEFROMPARTS(2023,12,25))';
28
+
--
29
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'What were the most ordered products in June 2008'
30
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'Which product category has the most products'
31
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'List all the red or black products and include the product model and category name'
32
+
--
33
+
-- -- These natural language queries work with the much larger AdventureWorksDW database
34
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'Return a 7-day rolling average number of sales grouped by territory, product and date ordered by date for any sales in 2012';
35
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'List salaried employees with the highest amount of sick leave and include their manager''s name in the list';
36
+
-- EXEC [dbo].[usp_ExecuteNaturalQuery] 'Which promotions, excluding "No Discount", had the largest total sales in the second quarter of 2012';
-- Do not remove the CODEONLY instruction if you plan on using the Natural Language Query feature
56
+
DECLARE @system_message NVARCHAR(MAX) = N'
57
+
You are a helpful database administrator and developer.
58
+
Your responses should always be for Transact SQL (or T-SQL).
59
+
When asked to generate a database object, you should generate the T-SQL script required to do this.
60
+
All T-SQL scripts should be formatted in the same way including data types are capitalised, column names are enclosed in square brackets.
61
+
For scripts containing a CREATE statement, make sure the script includes a check to see if that object already exists.
62
+
Only create the object if it doesn''t exist.
63
+
Scripts should only use dynamic SQL if required.
64
+
Try to avoid using sp_executesql.
65
+
If the request begins with CODEONLY, then the response must only contain T-SQL code and do not add any text before or after the T-SQL code - remove the term CODEONLY from the response.
66
+
';
67
+
43
68
-- Create Database Master Key; it's Azure SQL DB, so no password required
Here is a comma separated list of all the tables within a database:
565
+
'+ @full_table_list +'
566
+
567
+
To answer the following question, "'+ @query +'", which of those tables listed would you expect to need in a SQL query to answer the question.
568
+
569
+
Your response should contain only the names of the tables requires in a single comma separated list. The list should also include tables that might be helpful or useful in answering the response.
-- Formulate request for ChatGPT based on CREATE TABLE scripts for all relevant tables to answer the query
647
+
-- We use "CODEONLY" to tell ChatGPT to only return code (this is an instruction provided through the System Message)
648
+
SET @request = N'
649
+
CODEONLY
650
+
A database contains the following tables and columns:
651
+
'+ @create_table_prompt +'
652
+
Generate a T-SQL query to answer the question: "'+ @query +'" - the query should only reference table names and column names that appear in this request.
653
+
For example, if the request contains the following CREATE TABLE statements:
0 commit comments