diff --git a/src/Core/Models/GraphQLFilterParsers.cs b/src/Core/Models/GraphQLFilterParsers.cs index 153def832f..55554aa849 100644 --- a/src/Core/Models/GraphQLFilterParsers.cs +++ b/src/Core/Models/GraphQLFilterParsers.cs @@ -706,7 +706,7 @@ public static Predicate Parse( predicates.Push(new PredicateOperand(new Predicate( new PredicateOperand(column), op, - GenerateRightOperand(ctx, argumentObject, name, processLiterals, value, processLiteral) // right operand + GenerateRightOperand(ctx, argumentObject, name, processLiterals, value, processLiteral, column.ColumnName) // right operand ))); } @@ -760,6 +760,7 @@ public static Predicate Parse( /// A function to encode or parameterize literal values for database queries. /// The value to be used as the right operand in the predicate. /// Indicates whether to process the value as a literal using processLiterals, or use its string representation directly. + /// The name of the column being filtered, used to look up the column's DbType for proper parameter typing. /// A representing the right operand for the predicate. private static PredicateOperand GenerateRightOperand( IMiddlewareContext ctx, @@ -767,7 +768,8 @@ private static PredicateOperand GenerateRightOperand( string operationName, Func processLiterals, object value, - bool processLiteral) + bool processLiteral, + string? columnName) { if (operationName.Equals("in", StringComparison.OrdinalIgnoreCase)) { @@ -777,13 +779,13 @@ private static PredicateOperand GenerateRightOperand( argumentObject.Fields[operationName], ctx.Variables)) .Where(inValue => inValue is not null) - .Select(inValue => processLiterals(inValue!, null)) + .Select(inValue => processLiterals(inValue!, columnName)) .ToList(); return new PredicateOperand("(" + string.Join(", ", encodedParams) + ")"); } - return new PredicateOperand(processLiteral ? processLiterals(value, null) : value.ToString()); + return new PredicateOperand(processLiteral ? processLiterals(value, columnName) : value.ToString()); } private static string EscapeLikeString(string input) diff --git a/src/Core/Resolvers/IQueryExecutor.cs b/src/Core/Resolvers/IQueryExecutor.cs index 2eac7242de..1ab042daae 100644 --- a/src/Core/Resolvers/IQueryExecutor.cs +++ b/src/Core/Resolvers/IQueryExecutor.cs @@ -165,7 +165,7 @@ public Dictionary GetResultProperties( public string GetSessionParamsQuery(HttpContext? httpContext, IDictionary parameters, string dataSourceName); /// - /// Helper method to populate DbType for parameter. Currently DbTypes for parameters are only populated for MsSql. + /// Helper method to populate DbType for parameter. Currently DbTypes for parameters are only populated for MsSql and PostgreSql. /// /// Entry corresponding to current database parameter to be created. /// Parameter sent to database. diff --git a/src/Core/Resolvers/PostgreSqlExecutor.cs b/src/Core/Resolvers/PostgreSqlExecutor.cs index 70fa0f1079..873fa29167 100644 --- a/src/Core/Resolvers/PostgreSqlExecutor.cs +++ b/src/Core/Resolvers/PostgreSqlExecutor.cs @@ -1,6 +1,7 @@ // Copyright (c) Microsoft Corporation. // Licensed under the MIT License. +using System.Data; using System.Data.Common; using Azure.Core; using Azure.DataApiBuilder.Config; @@ -146,6 +147,52 @@ private static bool ShouldManagedIdentityAccessBeAttempted(NpgsqlConnectionStrin return string.IsNullOrEmpty(builder.Password); } + /// + public override NpgsqlCommand PrepareDbCommand( + NpgsqlConnection conn, + string sqltext, + IDictionary parameters, + HttpContext? httpContext, + string dataSourceName) + { + NpgsqlCommand cmd = conn.CreateCommand(); + cmd.CommandType = CommandType.Text; + + // Add query to send user data from DAB to the underlying database to enable additional security the user might have configured + // at the database level. + string sessionParamsQuery = GetSessionParamsQuery(httpContext, parameters, dataSourceName); + + cmd.CommandText = sessionParamsQuery + sqltext; + if (parameters is not null) + { + foreach (KeyValuePair parameterEntry in parameters) + { + NpgsqlParameter parameter = cmd.CreateParameter(); + parameter.ParameterName = parameterEntry.Key; + parameter.Value = parameterEntry.Value.Value ?? DBNull.Value; + PopulateDbTypeForParameter(parameterEntry, parameter); + cmd.Parameters.Add(parameter); + } + } + + return cmd; + } + + /// + /// Populates the DbType for a PostgreSQL parameter when available. + /// This ensures proper type handling for date/time and other types, + /// preventing errors like "operator does not exist: date >= text". + /// + /// The parameter entry containing the value and optional DbType. + /// The DbParameter to populate. + public override void PopulateDbTypeForParameter(KeyValuePair parameterEntry, DbParameter parameter) + { + if (parameterEntry.Value is not null && parameterEntry.Value.DbType is not null) + { + parameter.DbType = (DbType)parameterEntry.Value.DbType; + } + } + /// /// Determines if the saved default azure credential's access token is valid and not expired. /// diff --git a/src/Core/Resolvers/QueryExecutor.cs b/src/Core/Resolvers/QueryExecutor.cs index 97e2f7e8d4..9b026467db 100644 --- a/src/Core/Resolvers/QueryExecutor.cs +++ b/src/Core/Resolvers/QueryExecutor.cs @@ -420,7 +420,7 @@ public virtual string GetSessionParamsQuery(HttpContext? httpContext, IDictionar /// public virtual void PopulateDbTypeForParameter(KeyValuePair parameterEntry, DbParameter parameter) { - // DbType for parameter is currently only populated for MsSql which has its own overridden implementation. + // DbType for parameter is currently only populated for MsSql and PostgreSql which has its own overridden implementation. return; } diff --git a/src/Service.Tests/Configuration/ConfigurationTests.cs b/src/Service.Tests/Configuration/ConfigurationTests.cs index 9df54be519..a074fb3fc6 100644 --- a/src/Service.Tests/Configuration/ConfigurationTests.cs +++ b/src/Service.Tests/Configuration/ConfigurationTests.cs @@ -2846,7 +2846,7 @@ public async Task ValidateErrorMessageForMutationWithoutReadPermission() }"; string queryName = "stock_by_pk"; - ValidateMutationSucceededAtDbLayer(server, client, graphQLQuery, queryName, authToken, AuthorizationResolver.ROLE_AUTHENTICATED); + await ValidateMutationSucceededAtDbLayer(server, client, graphQLQuery, queryName, authToken, AuthorizationResolver.ROLE_AUTHENTICATED); } finally { @@ -3168,7 +3168,7 @@ public async Task ValidateInheritanceOfReadPermissionFromAnonymous() /// GraphQL query/mutation text /// GraphQL query/mutation name /// Auth token for the graphQL request - private static async void ValidateMutationSucceededAtDbLayer(TestServer server, HttpClient client, string query, string queryName, string authToken, string clientRoleHeader) + private static async Task ValidateMutationSucceededAtDbLayer(TestServer server, HttpClient client, string query, string queryName, string authToken, string clientRoleHeader) { JsonElement queryResponse = await GraphQLRequestExecutor.PostGraphQLRequestAsync( client, @@ -5672,12 +5672,12 @@ private static async Task GetGraphQLResponsePostConfigHydration( return responseCode; } - /// - /// Executing MCP POST requests against the engine until a non-503 error is received. - /// - /// Client used for request execution. - /// ServiceUnavailable if service is not successfully hydrated with config, - /// else the response code from the MCP request + /// + /// Executing MCP POST requests against the engine until a non-503 error is received. + /// + /// Client used for request execution. + /// ServiceUnavailable if service is not successfully hydrated with config, + /// else the response code from the MCP request public static async Task GetMcpResponse(HttpClient httpClient, McpRuntimeOptions mcp) { // Retry request RETRY_COUNT times in exponential increments to allow diff --git a/src/Service.Tests/DatabaseSchema-PostgreSql.sql b/src/Service.Tests/DatabaseSchema-PostgreSql.sql index 523e96c22f..98e560ee9e 100644 --- a/src/Service.Tests/DatabaseSchema-PostgreSql.sql +++ b/src/Service.Tests/DatabaseSchema-PostgreSql.sql @@ -161,6 +161,7 @@ CREATE TABLE type_table( float_types float, decimal_types decimal(38, 19), boolean_types boolean, + date_types date, datetime_types timestamp, bytearray_types bytea, uuid_types uuid DEFAULT gen_random_uuid () @@ -349,14 +350,14 @@ INSERT INTO bookmarks (id, bkname) SELECT value, CONCAT('Test Item #' , value) -FROM +FROM GENERATE_SERIES(1, 10000, 1) as value; INSERT INTO mappedbookmarks (id, bkname) SELECT value, CONCAT('Test Item #' , value) -FROM +FROM GENERATE_SERIES(1, 10000, 1) as value; INSERT INTO GQLmappings(__column1, __column2, column3) VALUES (1, 'Incompatible GraphQL Name', 'Compatible GraphQL Name'); @@ -366,7 +367,7 @@ INSERT INTO GQLmappings(__column1, __column2, column3) VALUES (5, 'Filtered Reco INSERT INTO publishers(id, name) VALUES (1234, 'Big Company'), (2345, 'Small Town Publisher'), (2323, 'TBD Publishing One'), (2324, 'TBD Publishing Two Ltd'), (1940, 'Policy Publisher 01'), (1941, 'Policy Publisher 02'), (1156, 'The First Publisher'); INSERT INTO clubs(id, name) VALUES (1111, 'Manchester United'), (1112, 'FC Barcelona'), (1113, 'Real Madrid'); INSERT INTO players(id, name, current_club_id, new_club_id) - VALUES + VALUES (1, 'Cristiano Ronaldo', 1113, 1111), (2, 'Leonel Messi', 1112, 1113); INSERT INTO authors(id, name, birthdate) VALUES (123, 'Jelte', '2001-01-01'), (124, 'Aniruddh', '2002-02-02'), (125, 'Aniruddh', '2001-01-01'), (126, 'Aaron', '2001-01-01'); @@ -405,12 +406,12 @@ VALUES (1, 'Star Trek', 'SciFi', NULL), (2, 'Cinderella', 'Tales', 3001),(3,'Ún INSERT INTO brokers("ID Number", "First Name", "Last Name") VALUES (1, 'Michael', 'Burry'), (2, 'Jordan', 'Belfort'); INSERT INTO stocks_price(categoryid, pieceid, price, is_wholesale_price) VALUES (2, 1, 100.57, True), (1, 1, 42.75, False); INSERT INTO stocks_price(categoryid, pieceid, instant, price, is_wholesale_price) VALUES (2, 1, '2023-08-21 15:11:04', 100.57, True); -INSERT INTO type_table(id, short_types, int_types, long_types, string_types, single_types, float_types, decimal_types, boolean_types, datetime_types, bytearray_types) VALUES - (1, 1, 1, 1, '', 0.33, 0.33, 0.333333, true, '1999-01-08 10:23:54', '\xABCDEF0123'), - (2, -1, -1, -1, 'lksa;jdflasdf;alsdflksdfkldj', -9.2, -9.2, -9.292929, false, '19990108 10:23:00', '\x98AB7511AABB1234'), - (3, -32768, -2147483648, -9223372036854775808, '', -3.4E38, -1.7E308, 2.929292E-19, true, '1753-01-01 00:00:00.000', '\x00000000'), - (4, 32767, 2147483647, 9223372036854775807, 'null', 3.4E38, 1.7E308, 2.929292E-14, true, '9999-12-31 23:59:59.997', '\xFFFFFFFF'), - (5, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL); +INSERT INTO type_table(id, short_types, int_types, long_types, string_types, single_types, float_types, decimal_types, boolean_types, date_types, datetime_types, bytearray_types) VALUES + (1, 1, 1, 1, '', 0.33, 0.33, 0.333333, true, '1999-01-08', '1999-01-08 10:23:54', '\xABCDEF0123'), + (2, -1, -1, -1, 'lksa;jdflasdf;alsdflksdfkldj', -9.2, -9.2, -9.292929, false, '2000-06-15', '19990108 10:23:00', '\x98AB7511AABB1234'), + (3, -32768, -2147483648, -9223372036854775808, '', -3.4E38, -1.7E308, 2.929292E-19, true, '1753-01-01', '1753-01-01 00:00:00.000', '\x00000000'), + (4, 32767, 2147483647, 9223372036854775807, 'null', 3.4E38, 1.7E308, 2.929292E-14, true, '9999-12-31', '9999-12-31 23:59:59.997', '\xFFFFFFFF'), + (5, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL); INSERT INTO type_table(id, uuid_types) values(10, 'D1D021A8-47B4-4AE4-B718-98E89C41A161'); INSERT INTO trees("treeId", species, region, height) VALUES (1, 'Tsuga terophylla', 'Pacific Northwest', '30m'), (2, 'Pseudotsuga menziesii', 'Pacific Northwest', '40m'); INSERT INTO trees("treeId", species, region, height) VALUES (4, 'test', 'Pacific Northwest', '0m'); diff --git a/src/Service.Tests/SqlTests/GraphQLSupportedTypesTests/PostgreSqlGQLSupportedTypesTests.cs b/src/Service.Tests/SqlTests/GraphQLSupportedTypesTests/PostgreSqlGQLSupportedTypesTests.cs index 8b6e399d45..bbfb170430 100644 --- a/src/Service.Tests/SqlTests/GraphQLSupportedTypesTests/PostgreSqlGQLSupportedTypesTests.cs +++ b/src/Service.Tests/SqlTests/GraphQLSupportedTypesTests/PostgreSqlGQLSupportedTypesTests.cs @@ -117,7 +117,6 @@ protected override bool IsSupportedType(string type) return type switch { BYTE_TYPE => false, - DATE_TYPE => false, SMALLDATETIME_TYPE => false, DATETIME2_TYPE => false, DATETIMEOFFSET_TYPE => false, @@ -142,6 +141,152 @@ private static string ProperlyFormatTypeTableColumn(string columnName) } } + /// + /// Tests DATE type filtering with various comparison operators. + /// This validates the fix for issue #3094 where DATE filtering failed with + /// "operator does not exist: date >= text" error. + /// The fix ensures DbType.Date is set on parameters to prevent ::text casting. + /// + [DataTestMethod] + [DataRow(DATE_TYPE, "eq", "'1999-01-08'", "\"1999-01-08\"", "=", + DisplayName = "DATE filter with eq operator")] + [DataRow(DATE_TYPE, "gt", "'1753-01-01'", "\"1753-01-01\"", ">", + DisplayName = "DATE filter with gt operator")] + [DataRow(DATE_TYPE, "gte", "'1999-01-08'", "\"1999-01-08\"", ">=", + DisplayName = "DATE filter with gte operator")] + [DataRow(DATE_TYPE, "lt", "'9999-12-31'", "\"9999-12-31\"", "<", + DisplayName = "DATE filter with lt operator")] + [DataRow(DATE_TYPE, "lte", "'2000-06-15'", "\"2000-06-15\"", "<=", + DisplayName = "DATE filter with lte operator")] + [DataRow(DATE_TYPE, "neq", "'1753-01-01'", "\"1753-01-01\"", "!=", + DisplayName = "DATE filter with neq operator")] + public async Task PostgreSQL_DateTypeFilterAndOrderBy( + string type, + string filterOperator, + string sqlValue, + string gqlValue, + string queryOperator) + { + await QueryTypeColumnFilterAndOrderBy(type, filterOperator, sqlValue, gqlValue, queryOperator); + } + + /// + /// Tests TIMESTAMP type filtering with various comparison operators. + /// This validates the fix for issue #3094 where TIMESTAMP filtering failed with + /// "operator does not exist: timestamp >= text" error. + /// The fix ensures DbType.DateTime is set on parameters to prevent ::text casting. + /// + [DataTestMethod] + [DataRow(DATETIME_TYPE, "eq", "'1999-01-08 10:23:54'", "\"1999-01-08 10:23:54\"", "=", + DisplayName = "TIMESTAMP filter with eq operator")] + [DataRow(DATETIME_TYPE, "gt", "'1753-01-01 00:00:00'", "\"1753-01-01 00:00:00\"", ">", + DisplayName = "TIMESTAMP filter with gt operator")] + [DataRow(DATETIME_TYPE, "gte", "'1999-01-08 10:23:00'", "\"1999-01-08 10:23:00\"", ">=", + DisplayName = "TIMESTAMP filter with gte operator")] + [DataRow(DATETIME_TYPE, "lt", "'9999-12-31 23:59:59'", "\"9999-12-31 23:59:59\"", "<", + DisplayName = "TIMESTAMP filter with lt operator")] + [DataRow(DATETIME_TYPE, "lte", "'1999-01-08 10:23:54'", "\"1999-01-08 10:23:54\"", "<=", + DisplayName = "TIMESTAMP filter with lte operator")] + [DataRow(DATETIME_TYPE, "neq", "'1753-01-01 00:00:00'", "\"1753-01-01 00:00:00\"", "!=", + DisplayName = "TIMESTAMP filter with neq operator")] + public async Task PostgreSQL_TimestampTypeFilterAndOrderBy( + string type, + string filterOperator, + string sqlValue, + string gqlValue, + string queryOperator) + { + await QueryTypeColumnFilterAndOrderBy(type, filterOperator, sqlValue, gqlValue, queryOperator); + } + + /// + /// Tests the specific scenario from issue #3094: + /// GraphQL query with gte filter on a date field should work without + /// "operator does not exist: date >= text" error. + /// + /// Example query that should work: + /// query { + /// supportedTypes(filter: { date_types: { gte: "2024-01-01" } }) { + /// items { date_types } + /// } + /// } + /// + [TestMethod] + public async Task PostgreSQL_DateGteFilter_NoTextCastingError() + { + if (!IsSupportedType(DATE_TYPE)) + { + Assert.Inconclusive("DATE type not supported"); + } + + string field = "date_types"; + string graphQLQueryName = "supportedTypes"; + string gqlQuery = @"{ + supportedTypes(first: 100 orderBy: { typeid: ASC } filter: { " + field + @": { gte: ""1999-01-08"" } }) { + items { + typeid, " + field + @" + } + } + }"; + + // Execute the query - this should not throw "operator does not exist: date >= text" + System.Text.Json.JsonElement actual = await ExecuteGraphQLRequestAsync(gqlQuery, graphQLQueryName, isAuthenticated: false); + + // Verify we got results (not an error) + Assert.IsTrue(actual.TryGetProperty("items", out System.Text.Json.JsonElement items), "Expected 'items' property in response"); + Assert.IsTrue(items.GetArrayLength() > 0, "Expected at least one result for gte filter on date"); + } + + /// + /// Tests the specific scenario from issue #3094: + /// GraphQL query with gte filter on a timestamp field should work without + /// "operator does not exist: timestamp >= text" error. + /// + [TestMethod] + public async Task PostgreSQL_TimestampGteFilter_NoTextCastingError() + { + if (!IsSupportedType(DATETIME_TYPE)) + { + Assert.Inconclusive("DATETIME type not supported"); + } + + string field = "datetime_types"; + string graphQLQueryName = "supportedTypes"; + string gqlQuery = @"{ + supportedTypes(first: 100 orderBy: { typeid: ASC } filter: { " + field + @": { gte: ""1999-01-08T00:00:00.000Z"" } }) { + items { + typeid, " + field + @" + } + } + }"; + + // Execute the query - this should not throw "operator does not exist: timestamp >= text" + System.Text.Json.JsonElement actual = await ExecuteGraphQLRequestAsync(gqlQuery, graphQLQueryName, isAuthenticated: false); + + // Verify we got results (not an error) + Assert.IsTrue(actual.TryGetProperty("items", out System.Text.Json.JsonElement items), "Expected 'items' property in response"); + Assert.IsTrue(items.GetArrayLength() > 0, "Expected at least one result for gte filter on timestamp"); + } + + /// + /// Tests that other type conversions (int, string, boolean, etc.) are not broken + /// by the date/time DbType fix. + /// + [DataTestMethod] + [DataRow(INT_TYPE, "eq", "1", "1", "=", DisplayName = "Int filter still works")] + [DataRow(STRING_TYPE, "eq", "'lksa;jdflasdf;alsdflksdfkldj'", "\"lksa;jdflasdf;alsdflksdfkldj\"", "=", DisplayName = "String filter still works")] + [DataRow(BOOLEAN_TYPE, "eq", "'true'", "true", "=", DisplayName = "Boolean filter still works")] + [DataRow(DECIMAL_TYPE, "eq", "0.333333", "0.333333", "=", DisplayName = "Decimal filter still works")] + public async Task PostgreSQL_OtherTypeFilters_NotBroken( + string type, + string filterOperator, + string sqlValue, + string gqlValue, + string queryOperator) + { + await QueryTypeColumnFilterAndOrderBy(type, filterOperator, sqlValue, gqlValue, queryOperator); + } + /// /// Bypass DateTime GQL tests for PostreSql /// diff --git a/src/Service.Tests/UnitTests/PostgreSqlQueryExecutorUnitTests.cs b/src/Service.Tests/UnitTests/PostgreSqlQueryExecutorUnitTests.cs index 6039c46a72..2c0afa00b8 100644 --- a/src/Service.Tests/UnitTests/PostgreSqlQueryExecutorUnitTests.cs +++ b/src/Service.Tests/UnitTests/PostgreSqlQueryExecutorUnitTests.cs @@ -3,10 +3,13 @@ using System; using System.Collections.Generic; +using System.Data; +using System.Data.Common; using System.Threading.Tasks; using Azure.Core; using Azure.DataApiBuilder.Config.ObjectModel; using Azure.DataApiBuilder.Core.Configurations; +using Azure.DataApiBuilder.Core.Models; using Azure.DataApiBuilder.Core.Resolvers; using Azure.Identity; using Microsoft.AspNetCore.Http; @@ -115,5 +118,291 @@ await provider.Initialize( Assert.AreEqual(connectionString, conn.ConnectionString); } } + + #region PrepareDbCommand Tests + + /// + /// Validates that PrepareDbCommand creates a command with the correct SQL text. + /// + [TestMethod] + public void PrepareDbCommand_WithSqlText_SetsCommandTextCorrectly() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM users WHERE id = @id"; + Dictionary parameters = new(); + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, parameters, null, string.Empty); + + // Assert + Assert.AreEqual(CommandType.Text, cmd.CommandType); + Assert.IsTrue(cmd.CommandText.EndsWith(sqlText)); + } + + /// + /// Validates that PrepareDbCommand correctly adds parameters with their values. + /// + [TestMethod] + public void PrepareDbCommand_WithParameters_AddsParametersCorrectly() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM users WHERE id = @id AND name = @name"; + Dictionary parameters = new() + { + { "@id", new DbConnectionParam(123) }, + { "@name", new DbConnectionParam("TestUser") } + }; + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, parameters, null, string.Empty); + + // Assert + Assert.AreEqual(2, cmd.Parameters.Count); + Assert.AreEqual(123, cmd.Parameters["@id"].Value); + Assert.AreEqual("TestUser", cmd.Parameters["@name"].Value); + } + + /// + /// Validates that PrepareDbCommand correctly handles null parameter values by converting to DBNull.Value. + /// + [TestMethod] + public void PrepareDbCommand_WithNullParameterValue_SetsDbNullValue() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM users WHERE name = @name"; + Dictionary parameters = new() + { + { "@name", new DbConnectionParam(null) } + }; + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, parameters, null, string.Empty); + + // Assert + Assert.AreEqual(1, cmd.Parameters.Count); + Assert.AreEqual(DBNull.Value, cmd.Parameters["@name"].Value); + } + + /// + /// Validates that PrepareDbCommand correctly sets DbType when provided in the parameter. + /// + [DataTestMethod] + [DataRow(DbType.Date, DisplayName = "DbType.Date is set correctly")] + [DataRow(DbType.DateTime, DisplayName = "DbType.DateTime is set correctly")] + [DataRow(DbType.DateTime2, DisplayName = "DbType.DateTime2 is set correctly")] + [DataRow(DbType.Time, DisplayName = "DbType.Time is set correctly")] + [DataRow(DbType.Int32, DisplayName = "DbType.Int32 is set correctly")] + [DataRow(DbType.String, DisplayName = "DbType.String is set correctly")] + [DataRow(DbType.Boolean, DisplayName = "DbType.Boolean is set correctly")] + [DataRow(DbType.Decimal, DisplayName = "DbType.Decimal is set correctly")] + [DataRow(DbType.Guid, DisplayName = "DbType.Guid is set correctly")] + public void PrepareDbCommand_WithDbType_SetsDbTypeCorrectly(DbType dbType) + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM events WHERE event_date = @eventDate"; + Dictionary parameters = new() + { + { "@eventDate", new DbConnectionParam(DateTime.Now, dbType) } + }; + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, parameters, null, string.Empty); + + // Assert + Assert.AreEqual(1, cmd.Parameters.Count); + Assert.AreEqual(dbType, cmd.Parameters["@eventDate"].DbType); + } + + /// + /// Validates that PrepareDbCommand handles empty parameters dictionary correctly. + /// + [TestMethod] + public void PrepareDbCommand_WithEmptyParameters_CreatesCommandWithNoParameters() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM users"; + Dictionary parameters = new(); + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, parameters, null, string.Empty); + + // Assert + Assert.AreEqual(0, cmd.Parameters.Count); + Assert.IsTrue(cmd.CommandText.EndsWith(sqlText)); + } + + /// + /// Validates that PrepareDbCommand handles null parameters dictionary correctly. + /// + [TestMethod] + public void PrepareDbCommand_WithNullParameters_CreatesCommandWithNoParameters() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + using NpgsqlConnection conn = new(connectionString); + const string sqlText = "SELECT * FROM users"; + + // Act + using NpgsqlCommand cmd = executor.PrepareDbCommand(conn, sqlText, null!, null, string.Empty); + + // Assert + Assert.AreEqual(0, cmd.Parameters.Count); + } + + #endregion + + #region PopulateDbTypeForParameter Tests + + /// + /// Validates that PopulateDbTypeForParameter sets the DbType when it is provided. + /// + [DataTestMethod] + [DataRow(DbType.Date, DisplayName = "PopulateDbTypeForParameter sets DbType.Date")] + [DataRow(DbType.DateTime, DisplayName = "PopulateDbTypeForParameter sets DbType.DateTime")] + [DataRow(DbType.DateTime2, DisplayName = "PopulateDbTypeForParameter sets DbType.DateTime2")] + [DataRow(DbType.DateTimeOffset, DisplayName = "PopulateDbTypeForParameter sets DbType.DateTimeOffset")] + [DataRow(DbType.Time, DisplayName = "PopulateDbTypeForParameter sets DbType.Time")] + [DataRow(DbType.Int16, DisplayName = "PopulateDbTypeForParameter sets DbType.Int16")] + [DataRow(DbType.Int32, DisplayName = "PopulateDbTypeForParameter sets DbType.Int32")] + [DataRow(DbType.Int64, DisplayName = "PopulateDbTypeForParameter sets DbType.Int64")] + [DataRow(DbType.String, DisplayName = "PopulateDbTypeForParameter sets DbType.String")] + [DataRow(DbType.Boolean, DisplayName = "PopulateDbTypeForParameter sets DbType.Boolean")] + [DataRow(DbType.Double, DisplayName = "PopulateDbTypeForParameter sets DbType.Double")] + [DataRow(DbType.Decimal, DisplayName = "PopulateDbTypeForParameter sets DbType.Decimal")] + [DataRow(DbType.Guid, DisplayName = "PopulateDbTypeForParameter sets DbType.Guid")] + [DataRow(DbType.Binary, DisplayName = "PopulateDbTypeForParameter sets DbType.Binary")] + public void PopulateDbTypeForParameter_WithDbType_SetsDbTypeOnParameter(DbType expectedDbType) + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + KeyValuePair parameterEntry = new("@param", new DbConnectionParam("value", expectedDbType)); + using NpgsqlConnection conn = new(connectionString); + using NpgsqlCommand cmd = conn.CreateCommand(); + DbParameter parameter = cmd.CreateParameter(); + + // Act + executor.PopulateDbTypeForParameter(parameterEntry, parameter); + + // Assert + Assert.AreEqual(expectedDbType, parameter.DbType); + } + + /// + /// Validates that PopulateDbTypeForParameter does not modify DbType when it is null. + /// + [TestMethod] + public void PopulateDbTypeForParameter_WithNullDbType_DoesNotSetDbType() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + KeyValuePair parameterEntry = new("@param", new DbConnectionParam("value", dbType: null)); + using NpgsqlConnection conn = new(connectionString); + using NpgsqlCommand cmd = conn.CreateCommand(); + DbParameter parameter = cmd.CreateParameter(); + DbType originalDbType = parameter.DbType; + + // Act + executor.PopulateDbTypeForParameter(parameterEntry, parameter); + + // Assert + Assert.AreEqual(originalDbType, parameter.DbType); + } + + /// + /// Validates that PopulateDbTypeForParameter handles a null Value in DbConnectionParam correctly. + /// The DbType should still be set if provided. + /// + [TestMethod] + public void PopulateDbTypeForParameter_WithNullValueButDbType_SetsDbType() + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + KeyValuePair parameterEntry = new("@param", new DbConnectionParam(null, DbType.Date)); + using NpgsqlConnection conn = new(connectionString); + using NpgsqlCommand cmd = conn.CreateCommand(); + DbParameter parameter = cmd.CreateParameter(); + + // Act + executor.PopulateDbTypeForParameter(parameterEntry, parameter); + + // Assert + Assert.AreEqual(DbType.Date, parameter.DbType); + } + + /// + /// Validates that PopulateDbTypeForParameter correctly handles date types to prevent + /// "operator does not exist: date >= text" errors. + /// + [DataTestMethod] + [DataRow("2024-01-15", DbType.Date, DisplayName = "Date string with DbType.Date")] + [DataRow("2024-01-15T10:30:00", DbType.DateTime, DisplayName = "DateTime string with DbType.DateTime")] + [DataRow("10:30:00", DbType.Time, DisplayName = "Time string with DbType.Time")] + public void PopulateDbTypeForParameter_WithDateTimeTypes_SetsCorrectDbType(string value, DbType expectedDbType) + { + // Arrange + const string connectionString = "Server=localhost;Database=testdb;"; + PostgreSqlQueryExecutor executor = CreatePostgreSqlQueryExecutor(connectionString); + KeyValuePair parameterEntry = new("@dateParam", new DbConnectionParam(value, expectedDbType)); + using NpgsqlConnection conn = new(connectionString); + using NpgsqlCommand cmd = conn.CreateCommand(); + DbParameter parameter = cmd.CreateParameter(); + + // Act + executor.PopulateDbTypeForParameter(parameterEntry, parameter); + + // Assert + Assert.AreEqual(expectedDbType, parameter.DbType); + } + + #endregion + + #region Helper Methods + + /// + /// Creates a PostgreSqlQueryExecutor instance for testing. + /// + private static PostgreSqlQueryExecutor CreatePostgreSqlQueryExecutor(string connectionString) + { + RuntimeConfig mockConfig = new( + Schema: "", + DataSource: new(DatabaseType.PostgreSQL, connectionString, new()), + Runtime: new( + Rest: new(), + GraphQL: new(), + Mcp: new(), + Host: new(null, null) + ), + Entities: new(new Dictionary()) + ); + + RuntimeConfigProvider provider = TestHelper.GenerateInMemoryRuntimeConfigProvider(mockConfig); + Mock dbExceptionParser = new(provider); + Mock> queryExecutorLogger = new(); + Mock httpContextAccessor = new(); + + return new PostgreSqlQueryExecutor(provider, dbExceptionParser.Object, queryExecutorLogger.Object, httpContextAccessor.Object); + } + + #endregion } } +