42 lines
1.9 KiB
Transact-SQL
42 lines
1.9 KiB
Transact-SQL
-- Query log table for capturing form-based searches
|
|
-- Used to seed few-shot examples for NL2SQL agent
|
|
|
|
IF OBJECT_ID('dbo.controls_query_log', 'U') IS NULL
|
|
BEGIN
|
|
CREATE TABLE dbo.controls_query_log (
|
|
id INT IDENTITY(1,1) PRIMARY KEY,
|
|
user_query NVARCHAR(1000) NOT NULL, -- Natural-language description of the search
|
|
sql_template NVARCHAR(MAX) NOT NULL, -- Parameterized SQL (placeholders like :tag, :start, :end)
|
|
sql_template_hash AS CONVERT(VARBINARY(32), HASHBYTES('SHA2_256', sql_template)) PERSISTED, -- For indexing
|
|
params NVARCHAR(MAX) NULL, -- JSON blob of actual parameter values
|
|
source_form NVARCHAR(100) NULL, -- Which form generated this (e.g., 'opcsearch', 'trend')
|
|
user_session NVARCHAR(100) NULL, -- Optional: session or user identifier
|
|
execution_ms INT NULL, -- Optional: query execution time in milliseconds
|
|
row_count INT NULL, -- Optional: number of rows returned
|
|
created_at DATETIME2 NOT NULL DEFAULT SYSUTCDATETIME()
|
|
);
|
|
|
|
-- Index on hash for deduplication and fast lookup
|
|
CREATE NONCLUSTERED INDEX IX_controls_query_log_template_hash
|
|
ON dbo.controls_query_log (sql_template_hash)
|
|
INCLUDE (user_query, created_at);
|
|
|
|
-- Index for time-based analysis
|
|
CREATE NONCLUSTERED INDEX IX_controls_query_log_created
|
|
ON dbo.controls_query_log (created_at DESC)
|
|
INCLUDE (user_query, source_form);
|
|
END;
|
|
GO
|
|
|
|
-- View for distinct templates with example user queries
|
|
CREATE OR ALTER VIEW dbo.vw_controls_query_templates AS
|
|
SELECT
|
|
sql_template,
|
|
COUNT(*) AS usage_count,
|
|
MAX(user_query) AS sample_user_query,
|
|
MIN(created_at) AS first_used,
|
|
MAX(created_at) AS last_used
|
|
FROM dbo.controls_query_log
|
|
GROUP BY sql_template;
|
|
GO
|