Skip to content

Commit f2a97f3

Browse files
committed
Added NLQ to OpenAI version of T-SQL script
1 parent b3dc7ba commit f2a97f3

File tree

2 files changed

+289
-42
lines changed

2 files changed

+289
-42
lines changed

README.md

+1-1
Original file line numberDiff line numberDiff line change
@@ -62,7 +62,7 @@ The SQL Script should look similar to the screenshot below - once you've pasted
6262
> Expected costs for running this demonstration are around $2.30/day:
6363
> - Azure SQL Database (Standard S0): ~ $20/month
6464
> - Azure API Management (Developer SKU): ~ $50/month
65-
> - OpenAI Costs not included (but may be covered by Free/ChatGPT Plus subscriptions)
65+
> - OpenAI Costs not included (typically $10/month for 100K tokens/day)
6666
6767

6868
## Pre-requisites

sql/TSqlChatGPT.sql

+288-41
Original file line numberDiff line numberDiff 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))';
27-
--/
28-
--/ EXEC [dbo].[usp_ExplainObject] 'dbo.uspLogError';
29-
--/ EXEC [dbo].[usp_ExplainObject] '[SalesLT].[vProductAndDescription]';
30-
--/
31-
--/ EXEC [dbo].[usp_GenerateTestDataForTable] '[SalesLT].[Address]'
32-
--/
33-
--/ EXEC [dbo].[usp_GenerateUnitTestForObject] 'dbo.ufnGetSalesOrderStatusText';
34-
--/
35-
--/ EXEC [dbo].[usp_DescribeTableColumns] '[SalesLT].[SalesOrderDetail]';
36-
--/
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.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';
37+
--
38+
-- EXEC [dbo].[usp_ExplainObject] 'dbo.uspLogError';
39+
-- EXEC [dbo].[usp_ExplainObject] '[SalesLT].[vProductAndDescription]';
40+
--
41+
-- EXEC [dbo].[usp_GenerateTestDataForTable] '[SalesLT].[Address]'
42+
--
43+
-- EXEC [dbo].[usp_GenerateUnitTestForObject] 'dbo.ufnGetSalesOrderStatusText';
44+
--
45+
-- EXEC [dbo].[usp_DescribeTableColumns] '[SalesLT].[SalesOrderDetail]';
46+
--
3747

3848
DECLARE @openai_api_key NVARCHAR(255) = 'sk-XXXXXXXXXXXXXXXXXXXXXXXXXXXX',
3949
@apim_subscription_key NVARCHAR(255) = 'xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx',
4050
@apim_url NVARCHAR(255) = 'https://<your APIM resource name>.azure-api.net',
51+
@chatgpt_model_name VARCHAR(255) = 'gpt-3.5-turbo',
4152
@sql_cmd NVARCHAR(MAX);
4253

54+
-- (OPTIONAL): Customise your chat agent here
55+
-- 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+
4368
-- Create Database Master Key; it's Azure SQL DB, so no password required
4469
IF NOT EXISTS(SELECT * FROM sys.symmetric_keys WHERE [name] = '##MS_DatabaseMasterKey##')
4570
CREATE MASTER KEY;
@@ -73,6 +98,26 @@ END
7398
';
7499
EXEC sp_executesql @sql_cmd;
75100

101+
-- ChatGPT Model function so that this can be references from other procs/functions
102+
SET @sql_cmd = N'
103+
CREATE OR ALTER FUNCTION dbo.OpenAIChatGPTModel()
104+
RETURNS SYSNAME AS
105+
BEGIN
106+
RETURN N''' + @chatgpt_model_name + ''';
107+
END
108+
';
109+
EXEC sp_executesql @sql_cmd;
110+
111+
-- System Message function so that this can be referenced from other procs/functions
112+
SET @sql_cmd = N'
113+
CREATE OR ALTER FUNCTION dbo.OpenAIChatSystemMessage()
114+
RETURNS NVARCHAR(MAX) AS
115+
BEGIN
116+
RETURN N''' + STRING_ESCAPE(REPLACE(REPLACE(REPLACE(REPLACE(@system_message, N'''', N''''''), CHAR(9), N'\t'), CHAR(10), N'\n'), CHAR(13), N'\r'), 'json') + ''';
117+
END
118+
';
119+
EXEC sp_executesql @sql_cmd;
120+
76121
-- Drop/Create proc to Print long strings (useful given size of response from ChatGPT)
77122
IF EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND OBJECT_ID = OBJECT_ID('dbo.usp_PrintMax'))
78123
DROP PROCEDURE [dbo].[usp_PrintMax];
@@ -112,7 +157,8 @@ CREATE PROCEDURE [dbo].[usp_AskChatGPT]
112157
@response NVARCHAR(MAX) = NULL OUTPUT,
113158
@apim_url NVARCHAR(255) = NULL, -- If not provided, then default value retrieved using dbo.ApiManagementInstanceUrl()
114159
@timeout INT = 60,
115-
@print_response BIT = 1
160+
@print_response BIT = 1,
161+
@debug BIT = 0
116162
AS
117163
BEGIN
118164
SET NOCOUNT ON;
@@ -122,19 +168,35 @@ BEGIN
122168
@apim_openai_endpoint NVARCHAR(1000),
123169
@sql_cmd NVARCHAR(MAX),
124170
@status_code INT,
125-
@status_description NVARCHAR(4000);
171+
@status_description NVARCHAR(4000),
172+
@chatgpt_model VARCHAR(255),
173+
@system_message NVARCHAR(MAX),
174+
@debug_message NVARCHAR(MAX);
175+
176+
-- Print request (non prompt injected) if in debug mode
177+
IF @debug = 1
178+
BEGIN
179+
SET @debug_message = FORMAT(GETDATE(),'HH:mm:ss.ff') + ' - Request: ' + @message;
180+
EXEC [dbo].[usp_PrintMax] @debug_message;
181+
END
126182

127183
-- If no APIM URL provided, then set to default
128184
SELECT @apim_url = ISNULL(@apim_url, dbo.ApiManagementInstanceUrl())
129185

130186
-- Configure APIM API endpoint
131187
SET @apim_openai_endpoint = @apim_url + N'/chat/completions';
132188

189+
-- Get ChatGPT model name
190+
SELECT @chatgpt_model = dbo.OpenAIChatGPTModel();
191+
192+
-- Get System Message
193+
SELECT @system_message = ISNULL(dbo.OpenAIChatSystemMessage(),'You are an AI assistant that helps people find information.');
194+
133195
-- Now make sure the message is a single line; escape characters such as tab, newline and quote, and escape characters to ensure valid JSON
134196
SET @message = STRING_ESCAPE(REPLACE(REPLACE(REPLACE(REPLACE(@message, N'''', N''''''), CHAR(9), N'\t'), CHAR(10), N'\n'), CHAR(13), N'\r'), 'json');
135197

136198
-- Inject the message into the request payload using the gpt-3.5 model
137-
SET @request = N'{"model": "gpt-3.5-turbo","messages": [{"role": "user", "content": "' + @message + '"}]}'
199+
SET @request = N'{"model": "' + @chatgpt_model + '","messages": [{"role": "system", "content": "' + @system_message + '"},{"role": "user", "content": "' + @message + '"}]}'
138200

139201
-- Invoke APIM endpoint which wraps the OpenAI chat completion API
140202
EXEC sp_invoke_external_rest_endpoint
@@ -173,9 +235,17 @@ BEGIN
173235
IF @response IS NULL
174236
THROW 50000, 'It was not possible to extract a message response from the OpenAI Chat API', 1;
175237

176-
-- Print response if required
177-
IF @print_response = 1
238+
-- Print response if required (and not in debug mode)
239+
IF @print_response = 1 AND @debug = 0
178240
EXEC [dbo].[usp_PrintMax] @response;
241+
242+
-- Print request (non prompt injected) if in debug mode
243+
IF @debug = 1
244+
BEGIN
245+
SET @debug_message = FORMAT(GETDATE(),'HH:mm:ss.ff') + ' - Response: ' + @response;
246+
EXEC [dbo].[usp_PrintMax] @debug_message;
247+
END
248+
179249
END TRY
180250
BEGIN CATCH
181251

@@ -460,3 +530,180 @@ BEGIN
460530
DEALLOCATE procCursor;
461531
END;
462532
GO
533+
534+
-- Drop Proc if already exists
535+
IF EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND OBJECT_ID = OBJECT_ID('dbo.usp_GetRelevantTablePromptForNaturalQuery'))
536+
DROP PROCEDURE [dbo].[usp_GetRelevantTablePromptForNaturalQuery];
537+
GO
538+
539+
-- Return part of a ChatGPT prompt which contains a list of CREATE TABLE statements for all the tables relevant to a natural language query
540+
-- ChatGPT is fed the names of all the database tables as well as the natural languge query and asked to decide on what is relevant
541+
CREATE PROCEDURE [dbo].[usp_GetRelevantTablePromptForNaturalQuery]
542+
@query NVARCHAR(MAX),
543+
@table_prompt NVARCHAR(MAX) = NULL OUTPUT,
544+
@print_response BIT = 1,
545+
@debug BIT = 0
546+
AS
547+
BEGIN
548+
SET NOCOUNT ON;
549+
550+
BEGIN TRY
551+
DECLARE @request NVARCHAR(MAX),
552+
@response NVARCHAR(MAX),
553+
@full_table_list NVARCHAR(MAX),
554+
@table_name NVARCHAR(512),
555+
@create_table_sql NVARCHAR(MAX);
556+
557+
-- Get comma separated list of ALL database schemas/tables
558+
SELECT @full_table_list = STRING_AGG(QUOTENAME(TABLE_SCHEMA) + '.' + QUOTENAME(TABLE_NAME),', ')
559+
FROM INFORMATION_SCHEMA.TABLES
560+
WHERE TABLE_TYPE = 'BASE TABLE';
561+
562+
-- Formulate request for LLM
563+
SET @request = N'
564+
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.
570+
'
571+
-- Get LLM response
572+
EXEC [dbo].[usp_AskChatGPT] @request, @full_table_list OUTPUT, @print_response = 0, @debug = @debug;
573+
574+
-- Now create a cursor for each of the tables returned in the list
575+
SET @table_prompt = N'';
576+
DECLARE table_cursor CURSOR FOR
577+
SELECT LTRIM(RTRIM([value])) FROM STRING_SPLIT(@full_table_list, ',');
578+
579+
OPEN table_cursor;
580+
FETCH NEXT FROM table_cursor INTO @table_name;
581+
582+
WHILE @@FETCH_STATUS = 0
583+
BEGIN
584+
-- Generate the Create table script and append to the prompt
585+
EXEC dbo.usp_Generate_Create_Table_Sql @table_name, @create_table_sql OUTPUT;
586+
SET @table_prompt = @table_prompt + @create_table_sql + CHAR(13) + CHAR(10);
587+
588+
FETCH NEXT FROM table_cursor INTO @table_name;
589+
END
590+
591+
CLOSE table_cursor;
592+
DEALLOCATE table_cursor;
593+
594+
-- Print response if required
595+
IF @print_response = 1 AND @debug = 0
596+
EXEC [dbo].[usp_PrintMax] @table_prompt;
597+
598+
END TRY
599+
BEGIN CATCH
600+
601+
DECLARE @error_message NVARCHAR(4000) = ERROR_MESSAGE(),
602+
@error_severity INT = ERROR_SEVERITY(),
603+
@error_state INT = ERROR_STATE();
604+
605+
RAISERROR (@error_message, @error_severity, @error_state);
606+
607+
END CATCH
608+
609+
END;
610+
GO
611+
612+
-- Drop Proc if already exists
613+
IF EXISTS (SELECT * FROM sys.objects WHERE type = 'P' AND OBJECT_ID = OBJECT_ID('dbo.usp_ExecuteNaturalQuery'))
614+
DROP PROCEDURE [dbo].[usp_ExecuteNaturalQuery];
615+
GO
616+
617+
-- WARNING!!!
618+
-- This Stored Procedure may cause unintended consequences - by default this stored procedure will execute SQL generated by AI
619+
-- Avoid using on any production systems - or set the @execute_sql parameter to 0
620+
--
621+
-- Generate and execute a T-SQL statement based on natural language query
622+
-- Since ChatGPT can either ignore certain instructions, or hallucinate, the T-SQL generated may be invalid.
623+
-- Therefore the stored procedure runs through a number of retries until the query responds successfully.
624+
CREATE PROCEDURE [dbo].[usp_ExecuteNaturalQuery]
625+
@query NVARCHAR(MAX),
626+
@sql NVARCHAR(MAX) = NULL OUTPUT,
627+
@print_response BIT = 1,
628+
@execute_sql BIT = 1,
629+
@execute_sql_retries INT = 10,
630+
@debug BIT = 0
631+
AS
632+
BEGIN
633+
SET NOCOUNT ON;
634+
635+
BEGIN TRY
636+
DECLARE @request NVARCHAR(MAX),
637+
@response NVARCHAR(MAX),
638+
@create_table_prompt NVARCHAR(MAX),
639+
@query_succeeded BIT,
640+
@attempt INT,
641+
@debug_message NVARCHAR(MAX);
642+
643+
-- Get Create Table SQL prompt based on query
644+
EXEC [dbo].[usp_GetRelevantTablePromptForNaturalQuery] @query, @create_table_prompt OUTPUT, @print_response = 0, @debug = @debug;
645+
646+
-- 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:
654+
CREATE TABLE Table1 (Column1 VARCHAR(255), Column2 VARCHAR(255))
655+
CREATE TABLE Table2 (Column3 VARCHAR(255), Column4 VARCHAR(255))
656+
Then you should only reference Tables Table1 and Table2 and the query should only reference columns Column1, Column2, Column3 and Column4
657+
'
658+
-- Get ChatGPT response
659+
EXEC [dbo].[usp_AskChatGPT] @request, @sql OUTPUT, @print_response = 0, @debug = @debug;
660+
661+
-- Execute SQL if required
662+
IF @execute_sql = 1
663+
BEGIN
664+
SET @query_succeeded = 0;
665+
SET @attempt = 1
666+
667+
-- We keep trying until we either get a successful query response or we've exhaused all specified retry attempts
668+
WHILE (@query_succeeded = 0) AND (@attempt <= @execute_sql_retries)
669+
BEGIN
670+
BEGIN TRY
671+
EXEC sp_executesql @sql;
672+
SET @query_succeeded = 1;
673+
END TRY
674+
BEGIN CATCH
675+
-- Ignore error
676+
IF @debug = 1
677+
PRINT FORMAT(GETDATE(),'HH:mm:ss.ff') + ' - Error Occurred: ' + ERROR_MESSAGE()
678+
END CATCH
679+
IF @debug = 1
680+
BEGIN
681+
SET @debug_message = FORMAT(GETDATE(),'HH:mm:ss.ff') + ' - Attempt: ' + CAST(@attempt AS VARCHAR(10)) + ' ' + IIF(@query_succeeded = 0, 'Failed', 'Succeeded');
682+
EXEC [dbo].[usp_PrintMax] @debug_message;
683+
END
684+
SET @attempt = @attempt + 1;
685+
686+
-- We need to try again!
687+
IF (@query_succeeded = 0) AND (@attempt <= @execute_sql_retries)
688+
EXEC [dbo].[usp_AskChatGPT] @request, @sql OUTPUT, @print_response = 0, @debug = @debug;
689+
690+
END
691+
END
692+
693+
-- Print response if required (suppress this if we're in debug mode)
694+
IF @print_response = 1 AND @debug = 0
695+
EXEC [dbo].[usp_PrintMax] @sql;
696+
697+
END TRY
698+
BEGIN CATCH
699+
700+
DECLARE @error_message NVARCHAR(4000) = ERROR_MESSAGE(),
701+
@error_severity INT = ERROR_SEVERITY(),
702+
@error_state INT = ERROR_STATE();
703+
704+
RAISERROR (@error_message, @error_severity, @error_state);
705+
706+
END CATCH
707+
708+
END;
709+
GO

0 commit comments

Comments
 (0)