Skip to content

Commit 001ea9c

Browse files
committed
add DbaGPT proc
1 parent 68cfa7d commit 001ea9c

File tree

1 file changed

+306
-0
lines changed

1 file changed

+306
-0
lines changed

AI/spDbaGPT.sql

Lines changed: 306 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,306 @@
1+
create or alter procedure spDbaGPT (
2+
@prompt nvarchar(max)
3+
,@credential nvarchar(1000) = 'https://api.openai.com'
4+
,@max_tokens int = 8196
5+
,@timeout int = 120
6+
,@MaxLoop int = 50
7+
,@RawResp bit = 0
8+
)
9+
as
10+
11+
12+
exec('
13+
/*~
14+
Obtém informacoes de uma sessao especifica
15+
---
16+
@SessionId: Id da sessao
17+
*/
18+
create or alter proc #toolGetSessionId(@SessionId int, @result nvarchar(max) OUTPUT)
19+
as
20+
set @result = (
21+
select
22+
*
23+
,SqlText = st.text
24+
from
25+
sys.dm_exec_requests r
26+
outer apply
27+
sys.dm_exec_sql_text(r.sql_handle) st
28+
where
29+
r.session_id = @SessionId
30+
for json path
31+
)
32+
')
33+
34+
exec('
35+
/*~
36+
Obtém informacoes de tudo o que está rodando no ambiente
37+
---
38+
*/
39+
create or alter proc #toolGetRequests(@result nvarchar(max) OUTPUT)
40+
as
41+
set @result = (
42+
select
43+
r.*
44+
,s.program_name
45+
,s.login_name
46+
,s.login_time
47+
from
48+
sys.dm_exec_requests r
49+
inner join
50+
sys.dm_exec_sessions s
51+
on s.session_id = r.session_id
52+
for json path
53+
)
54+
')
55+
56+
exec('
57+
/*~
58+
Retorna diversas informacoes da instancia, como versao, data e hora atual, etc.
59+
---
60+
*/
61+
create or alter proc #toolsysInfo(@result nvarchar(max) OUTPUT)
62+
as
63+
set @result = (
64+
select
65+
data = getdate()
66+
,versao = @@version
67+
,*
68+
from
69+
sys.dm_os_sys_info
70+
for json path
71+
)
72+
')
73+
74+
75+
76+
77+
drop table if exists #procs;
78+
create table #procs(name sysname, id int, body varchar(8000), ProcName varchar(100));
79+
80+
insert into #Procs
81+
EXEC tempdb..sp_executesql N'
82+
select
83+
name
84+
,object_id
85+
,convert(varchar(8000),OBJECT_DEFINITION(object_id))
86+
,ProcName
87+
from
88+
(
89+
select
90+
*
91+
,ProcName = REGEXP_REPLACE(name,''_+[0-9A-F]+$'','''')
92+
from
93+
tempdb.sys.procedures
94+
where
95+
name like ''#tool%''
96+
) t
97+
where
98+
object_id(''tempdb..''+ProcName) is not null
99+
'
100+
101+
declare @Tools nvarchar(max) = (
102+
select
103+
type = 'function'
104+
,JSON_QUERY(f.[function]) as [function]
105+
from
106+
#procs
107+
cross apply (
108+
select
109+
doc = REGEXP_SUBSTR(body,'/\*~(.+)\*/',1,1,'s',1)
110+
) d
111+
cross apply (
112+
select
113+
type = 'object'
114+
,JSON_OBJECT(ParamName:JSON_OBJECT('type':'string', 'description':ParamDescription)) as properties
115+
from
116+
(
117+
select
118+
ParamName = JSON_VALUE(m.substring_matches,'$[0].value')
119+
,ParamDescription = JSON_VALUE(m.substring_matches,'$[1].value')
120+
from
121+
REGEXP_MATCHES(d.doc,'\@(.+):(.+)') m
122+
) P
123+
for json path ,without_array_wrapper
124+
) p(parameters)
125+
cross apply (
126+
select
127+
name = replace(ProcName,'#tool','')
128+
,description = TRIM(REGEXP_SUBSTR(d.doc,'[\s]+(.+?)\-\-\-',1,1,'s',1))
129+
,parameters = JSON_QUERY(p.parameters)
130+
for json path ,without_array_wrapper
131+
) f([function])
132+
for json path
133+
)
134+
135+
136+
137+
138+
declare
139+
@MessagesTable TABLE(role varchar(10), content varchar(max), tool_call_id varchar(100), tool_calls nvarchar(max))
140+
141+
142+
insert into @MessagesTable(role,content) values('system','Você é um assistente que roda diretamente de um SQL Server. Responda a mensagem do usuario. Responda com JSON.');
143+
insert into @MessagesTable(role,content) values('user',@prompt);
144+
145+
146+
147+
148+
149+
declare
150+
@body nvarchar(max)
151+
,@url nvarchar(1000) = 'https://api.openai.com/v1/chat/completions'
152+
,@results nvarchar(max)
153+
,@FinishReason varchar(100)
154+
,@Message nvarchar(max)
155+
,@ToolScripts nvarchar(max)
156+
157+
drop table if exists #ToolCalls;
158+
create table #ToolCalls (
159+
id varchar(100)
160+
,name varchar(100)
161+
,args varchar(max)
162+
)
163+
164+
declare @i int = 1;
165+
166+
while @i <= @MaxLoop
167+
begin
168+
set @i+=1;
169+
170+
set @body = (
171+
SELECT
172+
max_tokens = @max_tokens
173+
,model = 'gpt-4o-mini'
174+
,[messages] = (
175+
select
176+
role,content,tool_call_id,JSON_QUERY(tool_calls) as tool_calls
177+
From
178+
@MessagesTable for json path
179+
)
180+
,tools = JSON_QUERY(@Tools)
181+
,response_format = json_query('
182+
{
183+
"type":"json_schema"
184+
,"json_schema":{
185+
"name": "sql_answer"
186+
,"schema":{
187+
"type":"object"
188+
,"properties":{
189+
"lines":{
190+
"type":"array"
191+
,"items":{
192+
"type":"string"
193+
,"description":"Answer line"
194+
}
195+
}
196+
}
197+
}
198+
}
199+
}
200+
201+
')
202+
for json path,without_array_wrapper
203+
)
204+
205+
raiserror('Sending request: %s',0,1,@body) with nowait;
206+
exec sp_invoke_external_rest_endpoint @url,@body,@credential = @credential,@timeout = @timeout, @response = @results OUTPUT;
207+
208+
209+
set @FinishReason = json_value(@results,'$.result.choices[0].finish_reason');
210+
set @Message = json_query(@results,'$.result.choices[0].message');
211+
212+
if @FinishReason = 'tool_calls'
213+
begin
214+
truncate table #ToolCalls;
215+
216+
insert into #ToolCalls
217+
select
218+
*
219+
from
220+
openjson(@Message,'$.tool_calls') with (
221+
id varchar(100)
222+
,name varchar(200) '$.function.name'
223+
,arguments nvarchar(max) '$.function.arguments'
224+
)
225+
226+
227+
drop table if exists #ToolResults;
228+
create table #ToolResults(id varchar(100), result nvarchar(max));
229+
230+
231+
232+
select
233+
@ToolScripts = STRING_AGG('
234+
set @toolresult = null;
235+
EXEC #tool'+name+' @result = @toolresult OUTPUT '+isnull(','+a.params,'')+';
236+
insert into #ToolResults values('''+id+''',@toolresult);
237+
'
238+
collate database_default
239+
,char(13)+char(10)
240+
)
241+
from
242+
#ToolCalls
243+
cross apply (
244+
select
245+
STRING_AGG( '@'+[Key]+' = '''+REPLACE(value,'''','''')+'''' , ',')
246+
from
247+
openjson(args)
248+
) a(params)
249+
250+
set @ToolScripts = 'declare @ToolResult nvarchar(max); ' + @ToolScripts;
251+
252+
raiserror('INvoking tools: %s',0,1,@ToolScripts) with nowait;
253+
exec(@ToolScripts);
254+
255+
256+
insert into @MessagesTable(role,tool_calls)
257+
select 'assistant',JSON_QUERY(@Message,'$.tool_calls')
258+
259+
insert into @MessagesTable(role,content,tool_call_id)
260+
select 'tool',result,id From #ToolResults
261+
262+
continue;
263+
end
264+
265+
266+
267+
break;
268+
end
269+
270+
271+
if @RawResp = 1
272+
select @results;
273+
274+
drop table if exists #results;
275+
276+
select
277+
*
278+
into
279+
#results
280+
from
281+
openjson(@results,'$.result') with (
282+
resposta nvarchar(max) '$.choices[0].message.content'
283+
,finish_reason varchar(10) '$.choices[0].finish_reason'
284+
,total_tokens int '$.usage.total_tokens'
285+
,prompt_tokens int '$.usage.prompt_tokens'
286+
,completion_tokens int '$.usage.completion_tokens'
287+
)
288+
289+
290+
select
291+
*
292+
from
293+
#results
294+
295+
select
296+
jr.value as resposta
297+
from
298+
#results r
299+
cross apply
300+
openjson(resposta,'$.lines') jr
301+
302+
303+
304+
305+
306+

0 commit comments

Comments
 (0)