From bffab34ea3e43537ae94a8429524b8a52f079a98 Mon Sep 17 00:00:00 2001 From: Richard Conway Date: Thu, 30 Jan 2025 16:13:30 +0000 Subject: [PATCH] version number support and extended unit tests with testcontainer.mssql --- DotPrompt.Sql.Cli/Program.cs | 6 +- DotPrompt.Sql.Cli/prompts/basic.prompt | 2 +- DotPrompt.Sql.Test/DotPrompt.Sql.Test.csproj | 6 + DotPrompt.Sql.Test/TestSqlPromptEntity.cs | 231 +++++++++++------- DotPrompt.Sql/DatabaseConnector.cs | 9 + DotPrompt.Sql/DotPrompt.Sql.csproj | 2 + DotPrompt.Sql/IPromptRepository.cs | 19 ++ .../Resources/SqlQueries/AddSqlPrompt.sql | 86 +++++++ .../SqlQueries/CreateDefaultPromptTables.sql | 108 ++++++-- .../Resources/SqlQueries/LoadPrompts.sql | 42 +++- DotPrompt.Sql/SqlPromptLoader.cs | 139 ++--------- DotPrompt.Sql/SqlPromptRepository.cs | 130 ++++++++++ DotPrompt.Sql/SqlPromptStore.cs | 5 +- 13 files changed, 535 insertions(+), 250 deletions(-) create mode 100644 DotPrompt.Sql/IPromptRepository.cs create mode 100644 DotPrompt.Sql/Resources/SqlQueries/AddSqlPrompt.sql create mode 100644 DotPrompt.Sql/SqlPromptRepository.cs diff --git a/DotPrompt.Sql.Cli/Program.cs b/DotPrompt.Sql.Cli/Program.cs index a681a5c..b37f752 100644 --- a/DotPrompt.Sql.Cli/Program.cs +++ b/DotPrompt.Sql.Cli/Program.cs @@ -12,8 +12,10 @@ public static async Task Main(string[] args) var config = DatabaseConfigReader.ReadYamlConfig(args[1]); var connector = new DatabaseConnector(); var connection = await connector.ConnectToDatabase(config); - var loader = new SqlPromptLoader(connection); - await loader.AddSqlPrompt(entity); + IPromptRepository sqlRepository = new SqlPromptRepository(connection); + var loader = new SqlPromptLoader(sqlRepository); + bool upVersioned = await loader.AddSqlPrompt(entity); + Console.WriteLine($"Done: {upVersioned}"); var prompts = loader.Load(); foreach (var prompt in prompts) diff --git a/DotPrompt.Sql.Cli/prompts/basic.prompt b/DotPrompt.Sql.Cli/prompts/basic.prompt index 8a85183..dead211 100644 --- a/DotPrompt.Sql.Cli/prompts/basic.prompt +++ b/DotPrompt.Sql.Cli/prompts/basic.prompt @@ -1,6 +1,6 @@ model: claude-3-5-sonnet-latest config: - name: basic1 + name: basic outputFormat: text temperature: 0.9 maxTokens: 500 diff --git a/DotPrompt.Sql.Test/DotPrompt.Sql.Test.csproj b/DotPrompt.Sql.Test/DotPrompt.Sql.Test.csproj index 3750497..c99665e 100644 --- a/DotPrompt.Sql.Test/DotPrompt.Sql.Test.csproj +++ b/DotPrompt.Sql.Test/DotPrompt.Sql.Test.csproj @@ -11,7 +11,13 @@ + + + + + + diff --git a/DotPrompt.Sql.Test/TestSqlPromptEntity.cs b/DotPrompt.Sql.Test/TestSqlPromptEntity.cs index f054fa7..95e1584 100644 --- a/DotPrompt.Sql.Test/TestSqlPromptEntity.cs +++ b/DotPrompt.Sql.Test/TestSqlPromptEntity.cs @@ -1,121 +1,174 @@ -namespace DotPrompt.Sql.Test; - using System; using System.Collections.Generic; -using System.IO; +using System.Data; +using System.Data.SQLite; +using System.Reflection; +using Microsoft.Data.Sqlite; +using System.Threading.Tasks; +using Dapper; +using DotPrompt.Sql; +using Microsoft.Data.SqlClient; +using Testcontainers.MsSql; using Xunit; -public class SqlPromptEntityTests : IDisposable +public class SqlPromptRepositoryTests : IAsyncLifetime { - private readonly List _testFiles = new(); + private readonly MsSqlContainer _sqlServerContainer; + private IDbConnection _connection; + private SqlPromptRepository _repository; - // Helper method to create and track test YAML files - private void CreateTestYamlFile(string filePath, string content) + public SqlPromptRepositoryTests() { - File.WriteAllText(filePath, content); - _testFiles.Add(filePath); // Track the file for later cleanup + _sqlServerContainer = new MsSqlBuilder() + .WithImage("mcr.microsoft.com/mssql/server:2022-latest") + .WithPassword("YourStrong(!)Password") + .Build(); } - [Fact] - public void FromPromptFile_ValidYaml_ReturnsSqlPromptEntity() + public async Task InitializeAsync() { - // Arrange - string filePath = "test_prompt.yaml"; - string yamlContent = @" -model: gpt-4 -config: - name: TestPrompt - outputFormat: json - maxTokens: 200 - input: - parameters: - param1: value1 - param2: value2 - default: - param1: default1 - param2: default2 -prompts: - system: System message - user: User message"; - - CreateTestYamlFile(filePath, yamlContent); + await _sqlServerContainer.StartAsync(); - // Act - var result = SqlPromptEntity.FromPromptFile(filePath); + _connection = new SqlConnection(_sqlServerContainer.GetConnectionString()); + _connection.Open(); - // Assert - Assert.NotNull(result); - Assert.Equal("gpt-4", result.Model); - Assert.Equal("TestPrompt", result.PromptName); - Assert.Equal("json", result.OutputFormat); - Assert.Equal(200, result.MaxTokens); - Assert.Equal("System message", result.SystemPrompt); - Assert.Equal("User message", result.UserPrompt); - Assert.Equal("value1", result.Parameters["param1"]); - Assert.Equal("default1", result.Default["param1"]); + _repository = new SqlPromptRepository(_connection); + await InitializeDatabase(); } - [Fact] - public void FromPromptFile_FileDoesNotExist_ThrowsFileNotFoundException() + public Task DisposeAsync() { - // Arrange - string invalidPath = "non_existent.yaml"; + _sqlServerContainer.StopAsync(); + _connection?.Dispose(); + return Task.CompletedTask; + } + + private static string LoadSql(string resourceName) + { + // Get the assembly containing the embedded SQL files + var assembly = Assembly.Load("DotPrompt.Sql"); // Name of the referenced assembly + + // Find the full resource name (includes namespace path) + string? fullResourceName = assembly.GetManifestResourceNames() + .FirstOrDefault(name => name.EndsWith(resourceName, StringComparison.OrdinalIgnoreCase)); + + if (fullResourceName == null) + { + throw new FileNotFoundException($"Resource {resourceName} not found in assembly {assembly.FullName}"); + } + + // Read the embedded resource stream + using var stream = assembly.GetManifestResourceStream(fullResourceName); + using var reader = new StreamReader(stream); + return reader.ReadToEnd(); + } + private async Task InitializeDatabase() + { + string tables = LoadSql("CreateDefaultPromptTables.sql"); + await _connection.ExecuteAsync(tables); - // Act & Assert - var exception = Assert.Throws(() => SqlPromptEntity.FromPromptFile(invalidPath)); - Assert.Contains("The specified file was not found", exception.Message); + string procs = LoadSql("AddSqlPrompt.sql"); + await _connection.ExecuteAsync(procs); } [Fact] - public void FromPromptFile_MissingMandatoryFields_ThrowsException() + public async Task AddSqlPrompt_ValidPrompt_InsertsSuccessfully() { // Arrange - string filePath = "test_missing_optional.yaml"; - string yamlContent = @" -config: - name: TestPrompt - outputFormat: json - maxTokens: 100 -prompts: - system: Default system prompt - user: Default user prompt"; - - CreateTestYamlFile(filePath, yamlContent); - - // Act & Assert - Assert.Throws(() => SqlPromptEntity.FromPromptFile(filePath)); + var entity = new SqlPromptEntity + { + PromptName = "myprompt", + Model = "gpt4", + OutputFormat = "json", + MaxTokens = 500, + SystemPrompt = "Optimize SQL queries.", + UserPrompt = "Suggest indexing improvements.", + Parameters = new Dictionary + { + { "Temperature", "0.7" }, + { "TopP", "0.9" } + }, + Default = new Dictionary + { + { "Temperature", "0.5" } + } + }; + + // Act + bool result = await _repository.AddSqlPrompt(entity); + + // Assert + Assert.True(result, "Expected new prompt version to be inserted."); } [Fact] - public void FromPromptFile_InvalidDataType_ThrowsException() + public async Task AddSqlPrompt_SamePromptNoChanges_DoesNotInsertNewVersion() { // Arrange - string filePath = "test_invalid_type.yaml"; - string yamlContent = @" -model: gpt-4 -config: - name: TestPrompt - outputFormat: json - maxTokens: not_a_number -prompts: - system: System prompt - user: User prompt"; - - CreateTestYamlFile(filePath, yamlContent); - - // Act & Assert - Assert.Throws(() => SqlPromptEntity.FromPromptFile(filePath)); + var entity = new SqlPromptEntity + { + PromptName = "myprompt", + Model = "gpt4", + OutputFormat = "json", + MaxTokens = 200, + SystemPrompt = "Optimize SQL queries.", + UserPrompt = "Suggest indexing improvements.", + Parameters = new Dictionary + { + { "Temperature", "0.7" }, + { "TopP", "0.9" } + }, + Default = new Dictionary + { + { "Temperature", "0.5" } + } + }; + + await _repository.AddSqlPrompt(entity); // First insert + + // Act + bool result = await _repository.AddSqlPrompt(entity); // Try inserting again with no changes + + // Assert + Assert.False(result, "No new version should be inserted when nothing has changed."); } - // Cleanup method called after each test - public void Dispose() + [Fact] + public async Task AddSqlPrompt_WhenMaxTokensChanges_ShouldInsertNewVersion() { - foreach (var file in _testFiles) + // Arrange + var entity1 = new SqlPromptEntity { - if (File.Exists(file)) - { - File.Delete(file); - } - } + PromptName = "noprompt", + Model = "gpt4", + OutputFormat = "json", + MaxTokens = 500, + SystemPrompt = "Optimize SQL queries.", + UserPrompt = "Suggest indexing improvements.", + Parameters = new Dictionary { { "Temperature", "0.7" } }, + Default = new Dictionary { { "Temperature", "0.5" } } + }; + + var entity2 = new SqlPromptEntity + { + PromptName = "noprompt", // Same prompt name + Model = "gpt4", + OutputFormat = "json", + MaxTokens = 512, // Changed value + SystemPrompt = "Optimize SQL queries.", + UserPrompt = "Suggest indexing improvements.", + Parameters = new Dictionary { { "Temperature", "0.7" } }, + Default = new Dictionary { { "Temperature", "0.5" } } + }; + + await _repository.AddSqlPrompt(entity1); // Insert first version + + // Act + bool result = await _repository.AddSqlPrompt(entity2); + + // Assert + Assert.True(result, "A new version should be inserted when MaxTokens changes."); } + + } diff --git a/DotPrompt.Sql/DatabaseConnector.cs b/DotPrompt.Sql/DatabaseConnector.cs index 64a98fa..eb62b30 100644 --- a/DotPrompt.Sql/DatabaseConnector.cs +++ b/DotPrompt.Sql/DatabaseConnector.cs @@ -25,6 +25,7 @@ public async Task ConnectToDatabase(DatabaseConfig config) var connection = new SqlConnection(connectionString); await connection.OpenAsync(); await CreatePromptTables(connection); + await CreateStoredProcs(connection); Console.WriteLine("Connected to the database successfully!"); return connection; } @@ -42,6 +43,14 @@ private async Task CreatePromptTables(SqlConnection connection) await command.ExecuteNonQueryAsync(); } + private async Task CreateStoredProcs(SqlConnection connection) + { + // 1. Does the prompt table exist already + string? sqlCreate = DatabaseConfigReader.LoadQuery("AddSqlPrompt.sql"); + await using SqlCommand command = new SqlCommand(sqlCreate, connection); + await command.ExecuteNonQueryAsync(); + } + private static string BuildConnectionString(DatabaseConfig config) { if (config.AadAuthentication) diff --git a/DotPrompt.Sql/DotPrompt.Sql.csproj b/DotPrompt.Sql/DotPrompt.Sql.csproj index d1b3952..382308c 100644 --- a/DotPrompt.Sql/DotPrompt.Sql.csproj +++ b/DotPrompt.Sql/DotPrompt.Sql.csproj @@ -43,6 +43,8 @@ + + diff --git a/DotPrompt.Sql/IPromptRepository.cs b/DotPrompt.Sql/IPromptRepository.cs new file mode 100644 index 0000000..3748b1c --- /dev/null +++ b/DotPrompt.Sql/IPromptRepository.cs @@ -0,0 +1,19 @@ +namespace DotPrompt.Sql; + +/// +/// Defines a prompt repository which will be injected into a loader +/// +public interface IPromptRepository +{ + /// + /// Adds a SQL prompt and upversions the prompt if it's changed + /// + /// The prompt entity that is being added or upversioned + /// A boolean to denote whether it added the prompt or not + Task AddSqlPrompt(SqlPromptEntity entity); + /// + /// Loads all instances of the prompt from the catalog but only the latest versions + /// + /// An enumeration of prompts with different names + IEnumerable Load(); +} \ No newline at end of file diff --git a/DotPrompt.Sql/Resources/SqlQueries/AddSqlPrompt.sql b/DotPrompt.Sql/Resources/SqlQueries/AddSqlPrompt.sql new file mode 100644 index 0000000..87912a7 --- /dev/null +++ b/DotPrompt.Sql/Resources/SqlQueries/AddSqlPrompt.sql @@ -0,0 +1,86 @@ +CREATE OR ALTER PROCEDURE sp_AddSqlPrompt + @PromptName VARCHAR(255), + @Model VARCHAR(255), + @OutputFormat VARCHAR(255), + @MaxTokens INT, + @SystemPrompt NVARCHAR(MAX), + @UserPrompt NVARCHAR(MAX), + @Parameters PromptParameterType READONLY, -- Table-Valued Parameter + @Defaults ParameterDefaultType READONLY, -- Table-Valued Parameter + @IsNewVersion BIT OUTPUT -- New Output Parameter + AS +BEGIN + SET NOCOUNT ON; + + DECLARE @ExistingPromptId INT, @ExistingVersion INT, @NewVersion INT; + DECLARE @NewPromptId INT; + SET @IsNewVersion = 0; -- Default to false + + -- Get latest version of the prompt +SELECT TOP 1 + @ExistingPromptId = PromptId, + @ExistingVersion = VersionNumber +FROM PromptFile +WHERE PromptName = @PromptName +ORDER BY VersionNumber DESC; + +-- If no existing prompt, set version to 1, otherwise increment +SET @NewVersion = ISNULL(@ExistingVersion, 0) + 1; + + -- Check if any values have changed + IF NOT EXISTS ( + SELECT 1 + FROM PromptFile + WHERE PromptId = @ExistingPromptId + AND Model = @Model + AND OutputFormat = @OutputFormat + AND MaxTokens = @MaxTokens + AND SystemPrompt = @SystemPrompt + AND UserPrompt = @UserPrompt + ) + OR EXISTS ( + -- Parameters changed? + SELECT 1 FROM @Parameters p + WHERE NOT EXISTS ( + SELECT 1 FROM PromptParameters pp + WHERE pp.PromptId = @ExistingPromptId + AND pp.VersionNumber = @ExistingVersion + AND pp.ParameterName = p.ParameterName + AND pp.ParameterValue = p.ParameterValue + ) + ) + OR EXISTS ( + -- Defaults changed? + SELECT 1 FROM @Defaults d + WHERE NOT EXISTS ( + SELECT 1 FROM ParameterDefaults pd + JOIN PromptParameters pp ON pd.ParameterId = pp.ParameterId + WHERE pp.PromptId = @ExistingPromptId + AND pp.VersionNumber = @ExistingVersion + AND pd.VersionNumber = @ExistingVersion + AND pp.ParameterName = d.ParameterName + AND pd.DefaultValue = d.DefaultValue + ) + ) +BEGIN + -- Insert new version of the prompt +INSERT INTO PromptFile (PromptName, VersionNumber, CreatedAt, ModifiedAt, Model, OutputFormat, MaxTokens, SystemPrompt, UserPrompt) +VALUES (@PromptName, @NewVersion, GETUTCDATE(), GETUTCDATE(), @Model, @OutputFormat, @MaxTokens, @SystemPrompt, @UserPrompt); + +SET @NewPromptId = SCOPE_IDENTITY(); + + -- Insert new parameters +INSERT INTO PromptParameters (PromptId, VersionNumber, ParameterName, ParameterValue) +SELECT @NewPromptId, @NewVersion, p.ParameterName, p.ParameterValue +FROM @Parameters p; + +-- Insert new defaults +INSERT INTO ParameterDefaults (ParameterId, VersionNumber, DefaultValue) +SELECT pp.ParameterId, @NewVersion, d.DefaultValue +FROM @Defaults d + JOIN PromptParameters pp ON pp.PromptId = @NewPromptId AND pp.ParameterName = d.ParameterName; + +-- Set output flag to indicate a new version was inserted +SET @IsNewVersion = 1; +END; +END; \ No newline at end of file diff --git a/DotPrompt.Sql/Resources/SqlQueries/CreateDefaultPromptTables.sql b/DotPrompt.Sql/Resources/SqlQueries/CreateDefaultPromptTables.sql index 3df51a4..4ec0843 100644 --- a/DotPrompt.Sql/Resources/SqlQueries/CreateDefaultPromptTables.sql +++ b/DotPrompt.Sql/Resources/SqlQueries/CreateDefaultPromptTables.sql @@ -2,45 +2,89 @@ IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'PromptFile') BEGIN CREATE TABLE PromptFile ( - PromptId INT IDENTITY(1,1) PRIMARY KEY, - PromptName VARCHAR(255) NOT NULL UNIQUE, - CreatedAt DATETIMEOFFSET NULL, - ModifiedAt DATETIMEOFFSET NULL, - Model VARCHAR(255) NULL, - OutputFormat VARCHAR(255) NOT NULL DEFAULT '', - MaxTokens INT NOT NULL, - SystemPrompt NVARCHAR(MAX) NOT NULL DEFAULT '', - UserPrompt NVARCHAR(MAX) NOT NULL DEFAULT '' + PromptId INT IDENTITY(1,1) PRIMARY KEY, + PromptName VARCHAR(255) NOT NULL, + VersionNumber INT NOT NULL DEFAULT 1, + CreatedAt DATETIMEOFFSET NULL, + ModifiedAt DATETIMEOFFSET NULL, + Model VARCHAR(255) NULL, + OutputFormat VARCHAR(255) NOT NULL DEFAULT '', + MaxTokens INT NOT NULL, + SystemPrompt NVARCHAR(MAX) NOT NULL DEFAULT '', + UserPrompt NVARCHAR(MAX) NOT NULL DEFAULT '', + CONSTRAINT UQ_PromptName_Version UNIQUE (PromptName, VersionNumber) ); END; +-- Add VersionNumber column to PromptFile (if not exists) +IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'PromptFile' AND COLUMN_NAME = 'VersionNumber') +BEGIN +ALTER TABLE PromptFile ADD VersionNumber INT NOT NULL DEFAULT 1; +-- Ensure unique constraint exists +IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS WHERE TABLE_NAME = 'PromptFile' AND CONSTRAINT_NAME = 'UQ_PromptName_Version') +BEGIN +ALTER TABLE PromptFile ADD CONSTRAINT UQ_PromptName_Version UNIQUE (PromptName, VersionNumber); +END; +END; + -- Create the PromptParameters table if it doesn't exist IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'PromptParameters') BEGIN CREATE TABLE PromptParameters ( - ParameterId INT IDENTITY(1,1) PRIMARY KEY, - PromptId INT NOT NULL, - ParameterName VARCHAR(255) NOT NULL, - ParameterValue VARCHAR(255) NOT NULL, - CONSTRAINT FK_Parameters_PromptFile FOREIGN KEY (PromptId) - REFERENCES PromptFile(PromptId) ON DELETE CASCADE + ParameterId INT IDENTITY(1,1) PRIMARY KEY, + PromptId INT NOT NULL, + VersionNumber INT NOT NULL DEFAULT 1, + ParameterName VARCHAR(255) NOT NULL, + ParameterValue VARCHAR(255) NOT NULL, + CONSTRAINT FK_Parameters_PromptFile FOREIGN KEY (PromptId) + REFERENCES PromptFile(PromptId) ON DELETE CASCADE ); END; +-- Add VersionNumber column to PromptParameters (if not exists) +IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'PromptParameters' AND COLUMN_NAME = 'VersionNumber') +BEGIN +ALTER TABLE PromptParameters ADD VersionNumber INT NOT NULL DEFAULT 1; +END; + +-- Add Unique Constraint on (ParameterId, VersionNumber) in PromptParameters +IF NOT EXISTS ( + SELECT 1 FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS + WHERE TABLE_NAME = 'PromptParameters' AND CONSTRAINT_NAME = 'UQ_ParameterId_Version' +) +BEGIN +ALTER TABLE PromptParameters ADD CONSTRAINT UQ_ParameterId_Version UNIQUE (ParameterId, VersionNumber); +END; + -- Create the ParameterDefaults table if it doesn't exist IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'ParameterDefaults') BEGIN CREATE TABLE ParameterDefaults ( - DefaultId INT IDENTITY(1,1) PRIMARY KEY, - ParameterId INT NOT NULL, - DefaultValue VARCHAR(255) NOT NULL, - Description NVARCHAR(500) NULL, - CONSTRAINT FK_ParameterDefaults_PromptParameters FOREIGN KEY (ParameterId) - REFERENCES PromptParameters(ParameterId) ON DELETE CASCADE + DefaultId INT IDENTITY(1,1) PRIMARY KEY, + ParameterId INT NOT NULL, + VersionNumber INT NOT NULL DEFAULT 1, + DefaultValue VARCHAR(255) NOT NULL, + Description NVARCHAR(500) NULL, + CONSTRAINT FK_ParameterDefaults_PromptParameters FOREIGN KEY (ParameterId) + REFERENCES PromptParameters(ParameterId) ON DELETE CASCADE ); END; --- Create the index for PromptParameters.PromptId if it doesn't exist +-- Add VersionNumber column to ParameterDefaults (if not exists) +IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'ParameterDefaults' AND COLUMN_NAME = 'VersionNumber') +BEGIN +ALTER TABLE ParameterDefaults ADD VersionNumber INT NOT NULL DEFAULT 1; +END; + +-- Add Unique Constraint on (ParameterId, VersionNumber) in ParameterDefaults +IF NOT EXISTS ( + SELECT 1 FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS + WHERE TABLE_NAME = 'ParameterDefaults' AND CONSTRAINT_NAME = 'UQ_ParameterDefaults_ParameterId_Version' +) +BEGIN +ALTER TABLE ParameterDefaults ADD CONSTRAINT UQ_ParameterDefaults_ParameterId_Version UNIQUE (ParameterId, VersionNumber); +END; + IF NOT EXISTS ( SELECT 1 FROM sys.indexes WHERE name = 'IX_PromptParameters_PromptId' AND object_id = OBJECT_ID('PromptParameters') @@ -57,3 +101,23 @@ IF NOT EXISTS ( BEGIN CREATE INDEX IX_ParameterDefaults_ParameterId ON ParameterDefaults(ParameterId); END; + +-- Ensure PromptParameterType TVP exists +IF NOT EXISTS (SELECT * FROM sys.types WHERE name = 'PromptParameterType' AND is_table_type = 1) +BEGIN +CREATE TYPE PromptParameterType AS TABLE + ( + ParameterName VARCHAR(255), + ParameterValue VARCHAR(255) + ); +END; + +-- Ensure ParameterDefaultType TVP exists +IF NOT EXISTS (SELECT * FROM sys.types WHERE name = 'ParameterDefaultType' AND is_table_type = 1) +BEGIN +CREATE TYPE ParameterDefaultType AS TABLE + ( + ParameterName VARCHAR(255), + DefaultValue VARCHAR(255) + ); +END; \ No newline at end of file diff --git a/DotPrompt.Sql/Resources/SqlQueries/LoadPrompts.sql b/DotPrompt.Sql/Resources/SqlQueries/LoadPrompts.sql index c3e35a1..0b0865e 100644 --- a/DotPrompt.Sql/Resources/SqlQueries/LoadPrompts.sql +++ b/DotPrompt.Sql/Resources/SqlQueries/LoadPrompts.sql @@ -1,18 +1,34 @@ +WITH LatestPrompts AS ( + SELECT + PromptId, + PromptName, + CreatedAt, + ModifiedAt, + Model, + OutputFormat, + MaxTokens, + SystemPrompt, + UserPrompt, + VersionNumber, + ROW_NUMBER() OVER (PARTITION BY PromptName ORDER BY VersionNumber DESC) AS RowNum + FROM PromptFile +) SELECT - pf.PromptId, - pf.PromptName, - pf.CreatedAt, - pf.ModifiedAt, - pf.Model, - pf.OutputFormat, - pf.MaxTokens, - pf.SystemPrompt, - pf.UserPrompt, + lp.PromptId, + lp.PromptName, + lp.CreatedAt, + lp.ModifiedAt, + lp.Model, + lp.OutputFormat, + lp.MaxTokens, + lp.SystemPrompt, + lp.UserPrompt, pp.ParameterId, pp.ParameterName, pp.ParameterValue, pd.DefaultValue -FROM PromptFile pf - LEFT JOIN PromptParameters pp ON pf.PromptId = pp.PromptId - LEFT JOIN ParameterDefaults pd ON pp.ParameterId = pd.ParameterId -ORDER BY pf.PromptId \ No newline at end of file +FROM LatestPrompts lp + LEFT JOIN PromptParameters pp ON lp.PromptId = pp.PromptId AND lp.VersionNumber = pp.VersionNumber + LEFT JOIN ParameterDefaults pd ON pp.ParameterId = pd.ParameterId AND pp.VersionNumber = pd.VersionNumber +WHERE lp.RowNum = 1 +ORDER BY lp.PromptId; diff --git a/DotPrompt.Sql/SqlPromptLoader.cs b/DotPrompt.Sql/SqlPromptLoader.cs index f636f30..f347e88 100644 --- a/DotPrompt.Sql/SqlPromptLoader.cs +++ b/DotPrompt.Sql/SqlPromptLoader.cs @@ -1,138 +1,37 @@ -using System.Data; -using Dapper; - namespace DotPrompt.Sql; -using System; -using System.Collections.Generic; -using DotPrompt.Sql.Types; - /// -/// A class which defines CRUD operations for a SqlEntityPrompt +/// Loads a repository and executes crud operations against a prompt store /// -/// An Open IDBConnection for a SQL database -public class SqlPromptLoader(IDbConnection connection) +public class SqlPromptLoader { - private readonly IDbConnection _connection = connection; + private readonly IPromptRepository _promptRepository; /// - /// Adds a single SqlPromptEntity to the database + /// Takes an IPromptRepository and adds to the SQL store /// - /// The configured SqlEntityPrompt instance - /// An exception if there is a database connection or issue with a conflict - public async Task AddSqlPrompt(SqlPromptEntity? entity) + /// The prompt repository being injected + public SqlPromptLoader(IPromptRepository promptRepository) { - using var transaction = _connection.BeginTransaction(); - try - { - // Insert into PromptFile table and get the PromptId - string? insertPromptFileQuery = DatabaseConfigReader.LoadQuery("InsertPromptFile.sql"); - - if (insertPromptFileQuery != null) - { - var promptId = await _connection.ExecuteScalarAsync( - insertPromptFileQuery, - new - { - entity.PromptName, - CreatedAt = DateTimeOffset.UtcNow, - ModifiedAt = DateTimeOffset.UtcNow, - Model = entity.Model ?? (object)DBNull.Value, - entity.OutputFormat, - entity.MaxTokens, - entity.SystemPrompt, - entity.UserPrompt - }, - transaction - ); - - // Insert parameters into PromptParameters table - if (entity.Parameters != null) - foreach (var param in entity.Parameters) - { - string? insertParametersQuery = DatabaseConfigReader.LoadQuery("InsertPromptParameters.sql"); - - if (insertParametersQuery == null) continue; - var parameterId = await _connection.ExecuteScalarAsync( - insertParametersQuery, - new - { - PromptId = promptId, - ParameterName = param.Key, - ParameterValue = param.Value - }, - transaction - ); - - // Insert corresponding default values into ParameterDefaults table - object? defaultValue = null; - if (entity.Default != null && !entity.Default.TryGetValue(param.Key, out defaultValue)) - continue; - string? insertDefaultsQuery = DatabaseConfigReader.LoadQuery("InsertPromptDefaults.sql"); - - if (insertDefaultsQuery != null) - await _connection.ExecuteAsync( - insertDefaultsQuery, - new - { - ParameterId = parameterId, - DefaultValue = defaultValue ?? (object)DBNull.Value - }, - transaction - ); - } - } + _promptRepository = promptRepository; + } - transaction.Commit(); - } - catch (Exception ex) - { - transaction.Rollback(); - throw new ApplicationException($"Error inserting data: {ex.Message}", ex); - } + /// + /// Adds a new prompt to the repository + /// + /// The SQL prompt to add + /// Whether it successfully added verion 1 or more + public async Task AddSqlPrompt(SqlPromptEntity entity) + { + return await _promptRepository.AddSqlPrompt(entity); } /// - /// Loads a set of SQL prompts from the database + /// Loads all prompts from the store /// - /// A collection of SqlPromptEntity which can be converted back and forth into a prompt file + /// An enumeration of prompts from the store public IEnumerable Load() { - string? query = DatabaseConfigReader.LoadQuery("LoadPrompts.sql"); - - var promptDictionary = new Dictionary(); - - if (query != null) - { - var result = _connection.Query( - query, - (prompt, param) => - { - if (!promptDictionary.TryGetValue(prompt.PromptId, out var promptEntity)) - { - promptEntity = prompt; - promptEntity.Parameters = new Dictionary(); - promptEntity.Default = new Dictionary(); - promptDictionary.Add(prompt.PromptId, promptEntity); - } - - if (string.IsNullOrEmpty(param.ParameterName)) return promptEntity; - if (promptEntity.Parameters != null && !promptEntity.Parameters.ContainsKey(param.ParameterName)) - { - promptEntity.Parameters.Add(param.ParameterName, param.ParameterValue); - } - - if (promptEntity.Default == null || promptEntity.Default.ContainsKey(param.ParameterName)) - return promptEntity; - if (param.DefaultValue != null) - promptEntity.Default.Add(param.ParameterName, param.DefaultValue); - - return promptEntity; - }, - splitOn: "ParameterId" - ); - } - - return promptDictionary.Values; + return _promptRepository.Load(); } } \ No newline at end of file diff --git a/DotPrompt.Sql/SqlPromptRepository.cs b/DotPrompt.Sql/SqlPromptRepository.cs new file mode 100644 index 0000000..bdbf8ed --- /dev/null +++ b/DotPrompt.Sql/SqlPromptRepository.cs @@ -0,0 +1,130 @@ +using Dapper; +using System; +using System.Collections.Generic; +using System.Data; +using System.Threading.Tasks; +using DotPrompt.Sql; +using DotPrompt.Sql.Types; + +namespace DotPrompt.Sql; + +/// +/// +/// +/// +public class SqlPromptRepository(IDbConnection connection) : IPromptRepository +{ + private readonly IDbConnection _connection = connection; + + /// + /// Adds a single SqlPromptEntity to the database + /// + /// The configured SqlEntityPrompt instance + /// An exception if there is a database connection or issue with a conflict + public async Task AddSqlPrompt(SqlPromptEntity entity) + { + using var transaction = _connection.BeginTransaction(); + try + { + // Convert Parameters to a DataTable for TVP + var parametersTable = new DataTable(); + parametersTable.Columns.Add("ParameterName", typeof(string)); + parametersTable.Columns.Add("ParameterValue", typeof(string)); + + if (entity.Parameters != null) + { + foreach (var param in entity.Parameters) + { + parametersTable.Rows.Add(param.Key, param.Value); + } + } + + // Convert Defaults to a DataTable for TVP + var defaultsTable = new DataTable(); + defaultsTable.Columns.Add("ParameterName", typeof(string)); + defaultsTable.Columns.Add("DefaultValue", typeof(string)); + + if (entity.Default != null) + { + foreach (var def in entity.Default) + { + defaultsTable.Rows.Add(def.Key, def.Value); + } + } + + // Output parameter to check if a new version was inserted + var parameters = new DynamicParameters(); + parameters.Add("PromptName", entity.PromptName); + parameters.Add("Model", entity.Model); + parameters.Add("OutputFormat", entity.OutputFormat); + parameters.Add("MaxTokens", entity.MaxTokens); + parameters.Add("SystemPrompt", entity.SystemPrompt); + parameters.Add("UserPrompt", entity.UserPrompt); + parameters.Add("Parameters", parametersTable.AsTableValuedParameter("PromptParameterType")); + parameters.Add("Defaults", defaultsTable.AsTableValuedParameter("ParameterDefaultType")); + parameters.Add("IsNewVersion", dbType: DbType.Boolean, direction: ParameterDirection.Output); + + // Execute the stored procedure + await _connection.ExecuteAsync( + "sp_AddSqlPrompt", + parameters, + transaction, + commandType: CommandType.StoredProcedure + ); + + transaction.Commit(); + + // Return true if a new version was inserted, false otherwise + return parameters.Get("IsNewVersion"); + } + catch (Exception ex) + { + transaction.Rollback(); + throw new ApplicationException($"Error inserting data: {ex.Message}", ex); + } + } + + /// + /// Loads a set of SQL prompts from the database + /// + /// A collection of SqlPromptEntity which can be converted back and forth into a prompt file + public IEnumerable Load() + { + string? query = DatabaseConfigReader.LoadQuery("LoadPrompts.sql"); + + var promptDictionary = new Dictionary(); + + if (query != null) + { + var result = _connection.Query( + query, + (prompt, param) => + { + if (!promptDictionary.TryGetValue(prompt.PromptId, out var promptEntity)) + { + promptEntity = prompt; + promptEntity.Parameters = new Dictionary(); + promptEntity.Default = new Dictionary(); + promptDictionary.Add(prompt.PromptId, promptEntity); + } + + if (string.IsNullOrEmpty(param.ParameterName)) return promptEntity; + if (promptEntity.Parameters != null && !promptEntity.Parameters.ContainsKey(param.ParameterName)) + { + promptEntity.Parameters.Add(param.ParameterName, param.ParameterValue); + } + + if (promptEntity.Default == null || promptEntity.Default.ContainsKey(param.ParameterName)) + return promptEntity; + if (param.DefaultValue != null) + promptEntity.Default.Add(param.ParameterName, param.DefaultValue); + + return promptEntity; + }, + splitOn: "ParameterId" + ); + } + + return promptDictionary.Values; + } +} \ No newline at end of file diff --git a/DotPrompt.Sql/SqlPromptStore.cs b/DotPrompt.Sql/SqlPromptStore.cs index ed08493..5d0c028 100644 --- a/DotPrompt.Sql/SqlPromptStore.cs +++ b/DotPrompt.Sql/SqlPromptStore.cs @@ -6,7 +6,7 @@ namespace DotPrompt.Sql; /// /// Implementation of the IPromptStore for any SQL Server database /// -public class SqlTablePromptStore(string promptFile) : IPromptStore +public class SqlTablePromptStore(string promptFile, IPromptRepository repository) : IPromptStore { private readonly string _promptFile = promptFile; @@ -15,8 +15,7 @@ public class SqlTablePromptStore(string promptFile) : IPromptStore /// public IEnumerable Load() { - var sqlConnection = GetSqlClient(_promptFile).Result; - var loader = new SqlPromptLoader(sqlConnection); + var loader = new SqlPromptLoader(repository); var sqlPromptEntities = loader.Load(); return sqlPromptEntities.Select(entity => entity.ToPromptFile())!; }