From b5ad9bf190f0123b1e341899ffb3385e880e7343 Mon Sep 17 00:00:00 2001 From: Harry Greenhough Date: Thu, 16 Oct 2025 14:39:47 +1100 Subject: [PATCH 1/4] Failing test for Issue #718 - mssql only --- .../Databases/InsertTests.cs | 15 +++++++++++ .../Scripts/SqlServerBuildDatabase.sql | 26 +++++++++++++++++++ 2 files changed, 41 insertions(+) diff --git a/PetaPoco.Tests.Integration/Databases/InsertTests.cs b/PetaPoco.Tests.Integration/Databases/InsertTests.cs index 1f54efde..b62cfd28 100644 --- a/PetaPoco.Tests.Integration/Databases/InsertTests.cs +++ b/PetaPoco.Tests.Integration/Databases/InsertTests.cs @@ -432,5 +432,20 @@ public virtual async Task InsertAsync_GivenTableNamePrimaryKeyNameAndAnonymousTy otherPerson.Height.ShouldBe(person.Height); otherPerson.Name.ShouldBe(person.FullName); } + + [Fact] + public virtual async Task InsertAsync_GivenTableWithAutoIncrementIdAndTrigger_ShouldInsertPoco() + { + var id = await DB.InsertAsync("BugInvestigation_ISSUE178", _order); + + var insertedOrder = + await DB.SingleAsync( + $"SELECT * FROM {DB.Provider.EscapeTableName("BugInvestigation_ISSUE178")} WHERE {DB.Provider.EscapeSqlIdentifier("Id")} = @0", _order.Id); + + id.ShouldNotBeNull(); + insertedOrder.Id.ShouldBe(id); + insertedOrder.ShouldBe(_order); + } } + } diff --git a/PetaPoco.Tests.Integration/Scripts/SqlServerBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/SqlServerBuildDatabase.sql index c984d722..9715cac5 100644 --- a/PetaPoco.Tests.Integration/Scripts/SqlServerBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/SqlServerBuildDatabase.sql @@ -130,6 +130,32 @@ CREATE TABLE dbo.[BugInvestigation_5TN5C4U4] ( ) GO +IF EXISTS(SELECT * FROM INFORMATION_SCHEMA.TABLES t WHERE t.TABLE_SCHEMA = 'dbo' AND t.TABLE_NAME = 'BugInvestigation_ISSUE178') + DROP TABLE dbo.[BugInvestigation_ISSUE178] + +CREATE TABLE dbo.[BugInvestigation_ISSUE178] ( + [Id] INT IDENTITY(1,1) PRIMARY KEY, + [PersonId] UNIQUEIDENTIFIER NOT NULL, + [PoNumber] NVARCHAR(15) NOT NULL, + [OrderStatus] INT NOT NULL, + [CreatedOn] DATETIME2 NOT NULL, + [CreatedBy] NVARCHAR(255) NOT NULL, + [UpdatedAt] DATETIME NULL +); +GO + +CREATE TRIGGER Trigger_BugInvestigation_ISSUE178_UpdatedAt +ON dbo.[BugInvestigation_ISSUE178] +AFTER INSERT, UPDATE +AS +BEGIN + UPDATE dbo.[BugInvestigation_ISSUE178] + SET dbo.[BugInvestigation_ISSUE178].[UpdatedAt] = GETDATE() + FROM dbo.[BugInvestigation_ISSUE178] + INNER JOIN inserted i ON dbo.[BugInvestigation_ISSUE178].[Id] = i.[Id]; +END; +GO + -- Stored procedures IF EXISTS (SELECT * FROM sys.objects o WHERE o.type = 'P' AND o.NAME = 'SelectPeople') From af3da8129ec0e5448ec4c1c9de89e8630f723d5e Mon Sep 17 00:00:00 2001 From: Harry Greenhough Date: Fri, 17 Oct 2025 10:08:47 +1100 Subject: [PATCH 2/4] use OUTPUT ... INTO for sql server inserted id returning --- PetaPoco/Core/DatabaseProvider.cs | 6 ++++++ PetaPoco/Core/IProvider.cs | 18 ++++++++++++++++++ PetaPoco/Database.cs | 8 +++++++- .../Providers/SqlServerDatabaseProvider.cs | 10 +++++++++- 4 files changed, 40 insertions(+), 2 deletions(-) diff --git a/PetaPoco/Core/DatabaseProvider.cs b/PetaPoco/Core/DatabaseProvider.cs index 6485a169..1b95134b 100644 --- a/PetaPoco/Core/DatabaseProvider.cs +++ b/PetaPoco/Core/DatabaseProvider.cs @@ -68,6 +68,12 @@ public virtual string BuildPageQuery(long skip, long take, SQLParts parts, ref o /// public virtual string GetInsertOutputClause(string primaryKeyName) => string.Empty; + + /// + public virtual string GetInsertPreamble(string primaryKeyName) => string.Empty; + + /// + public virtual string GetInsertPostScript(string primaryKeyName) => string.Empty; /// public virtual object ExecuteInsert(Database db, IDbCommand cmd, string primaryKeyName) diff --git a/PetaPoco/Core/IProvider.cs b/PetaPoco/Core/IProvider.cs index 4f724173..4ccc1ca2 100644 --- a/PetaPoco/Core/IProvider.cs +++ b/PetaPoco/Core/IProvider.cs @@ -100,6 +100,24 @@ public interface IProvider /// The primary key column name of the row being inserted. /// An expression describing how to return the new primary key value. string GetInsertOutputClause(string primaryKeyName); + + /// + /// Return an SQL expression that can be used with + /// and to return a provider-generated value from an INSERT; typically an IDENTITY + /// column in Microsoft SQL Server. + /// + /// + /// + string GetInsertPreamble(string primaryKeyName); + + /// + /// Return an SQL expression that can be used with + /// and to return a provider-generated value from an INSERT; typically an IDENTITY + /// column in Microsoft SQL Server. + /// + /// + /// + string GetInsertPostScript(string primaryKeyName); /// /// Returns the prefix used to delimit parameters in SQL query strings. diff --git a/PetaPoco/Database.cs b/PetaPoco/Database.cs index 5a828997..c886b0ba 100644 --- a/PetaPoco/Database.cs +++ b/PetaPoco/Database.cs @@ -2094,11 +2094,17 @@ private void PrepareExecuteInsert(string tableName, string primaryKeyName, bool } var outputClause = string.Empty; + var insertPreamble = string.Empty; + var insertPostScript = string.Empty; if (autoIncrement) + { + insertPreamble = _provider.GetInsertPreamble(primaryKeyName); outputClause = _provider.GetInsertOutputClause(primaryKeyName); + insertPostScript = _provider.GetInsertPostScript(primaryKeyName); + } cmd.CommandText = - $"INSERT INTO {_provider.EscapeTableName(tableName)} ({string.Join(",", names.ToArray())}){outputClause} VALUES ({string.Join(",", values.ToArray())})"; + $"{insertPreamble}INSERT INTO {_provider.EscapeTableName(tableName)} ({string.Join(",", names.ToArray())}){outputClause} VALUES ({string.Join(",", values.ToArray())}){insertPostScript}"; } /// diff --git a/PetaPoco/Providers/SqlServerDatabaseProvider.cs b/PetaPoco/Providers/SqlServerDatabaseProvider.cs index cc72d13e..b40a3dce 100644 --- a/PetaPoco/Providers/SqlServerDatabaseProvider.cs +++ b/PetaPoco/Providers/SqlServerDatabaseProvider.cs @@ -63,6 +63,14 @@ public override string GetExistsSql() /// public override string GetInsertOutputClause(string primaryKeyName) - => $" OUTPUT INSERTED.[{primaryKeyName}]"; + => $" OUTPUT INSERTED.[{primaryKeyName}] into @result({primaryKeyName})"; + + /// + public override string GetInsertPreamble(string primaryKeyName) + => $"DECLARE @result TABLE({primaryKeyName} sql_variant); "; + + /// + public override string GetInsertPostScript(string primaryKeyName) + => $"; SELECT {primaryKeyName} FROM @result; "; } } From f76af0afeff0af3601b523df5b9f6cdd72d0a915 Mon Sep 17 00:00:00 2001 From: Harry Greenhough Date: Fri, 17 Oct 2025 12:54:27 +1100 Subject: [PATCH 3/4] add Sync Test --- .../Databases/InsertTests.cs | 14 ++++++++++++++ 1 file changed, 14 insertions(+) diff --git a/PetaPoco.Tests.Integration/Databases/InsertTests.cs b/PetaPoco.Tests.Integration/Databases/InsertTests.cs index b62cfd28..c303e010 100644 --- a/PetaPoco.Tests.Integration/Databases/InsertTests.cs +++ b/PetaPoco.Tests.Integration/Databases/InsertTests.cs @@ -240,6 +240,20 @@ public virtual void Insert_GivenTableNamePrimaryKeyNameAndAnonymousTypeWithStati otherPerson.Height.ShouldBe(person.Height); otherPerson.Name.ShouldBe(person.FullName); } + + [Fact] + public virtual void Insert_GivenTableWithAutoIncrementIdAndTrigger_ShouldInsertPoco() + { + var id = DB.Insert("BugInvestigation_ISSUE178", _order); + + var insertedOrder = + DB.Single( + $"SELECT * FROM {DB.Provider.EscapeTableName("BugInvestigation_ISSUE178")} WHERE {DB.Provider.EscapeSqlIdentifier("Id")} = @0", _order.Id); + + id.ShouldNotBeNull(); + insertedOrder.Id.ShouldBe(id); + insertedOrder.ShouldBe(_order); + } [Fact] public virtual async Task InsertAsync_GivenPoco_ShouldBeValid() From 956639ddb91aa59f5d3149b91f9ec047ebd7a285 Mon Sep 17 00:00:00 2001 From: Harry Greenhough Date: Fri, 17 Oct 2025 12:54:49 +1100 Subject: [PATCH 4/4] sql for other DBs --- .../Scripts/FirebirdBuildDatabase.sql | 44 +++++++++++++++++++ .../Scripts/MSAccessBuildDatabase.sql | 12 +++++ .../Scripts/MariaDBBuildDatabase.sql | 26 +++++++++++ .../Scripts/MySqlBuildDatabase.sql | 12 +++++ .../Scripts/PostgresBuildDatabase.sql | 25 +++++++++++ .../Scripts/SQLiteBuildDatabase.sql | 28 ++++++++++++ 6 files changed, 147 insertions(+) diff --git a/PetaPoco.Tests.Integration/Scripts/FirebirdBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/FirebirdBuildDatabase.sql index f2d5c905..8613b10b 100644 --- a/PetaPoco.Tests.Integration/Scripts/FirebirdBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/FirebirdBuildDatabase.sql @@ -326,6 +326,50 @@ CREATE TABLE "BugInvestigation_5TN5C4U4" ( "Column2" VARCHAR(20) ); +SET TERM !! ; +EXECUTE BLOCK AS +BEGIN + IF (EXISTS(SELECT 1 FROM RDB$RELATIONS WHERE RDB$RELATION_NAME = 'BugInvestigation_ISSUE178')) THEN EXECUTE STATEMENT 'DROP TABLE "BugInvestigation_ISSUE178";'; +END!! +SET TERM ; !! + +CREATE TABLE "BugInvestigation_ISSUE178" ( + "Id" INT PRIMARY KEY NOT NULL, + "PersonId" CHAR(36) NOT NULL, + "PoNumber" VARCHAR(15) NOT NULL, + "OrderStatus" INT NOT NULL, + "CreatedOn" TIMESTAMP NOT NULL, + "CreatedBy" VARCHAR(255) NOT NULL, + "UpdatedAt" TIMESTAMP +); + +SET TERM !! ; +EXECUTE BLOCK AS BEGIN + if (exists(SELECT 1 FROM rdb$generators WHERE rdb$generator_name = 'GEN_BI_178_ID')) then execute statement 'DROP SEQUENCE GEN_BI_178_ID;'; +END!! +SET TERM ; !! + +CREATE SEQUENCE GEN_BI_178_ID; +ALTER SEQUENCE GEN_BI_178_ID RESTART WITH 0; + +SET TERM !! ; +CREATE TRIGGER trigger_BI_178_id FOR "BugInvestigation_ISSUE178" +ACTIVE BEFORE INSERT POSITION 0 +AS +BEGIN + IF (NEW."Id" is NULL) THEN NEW."Id" = GEN_ID(GEN_BI_178_ID, 1); +END!! +SET TERM ; !! + +SET TERM !! ; +CREATE OR ALTER TRIGGER "BI_ISSUE178_UPDATEDAT" +ACTIVE BEFORE INSERT OR UPDATE ON "BugInvestigation_ISSUE178" +AS +BEGIN + NEW."UpdatedAt" = CURRENT_TIMESTAMP; +END!! +SET TERM ; !! + -- Stored procedures SET TERM !! ; diff --git a/PetaPoco.Tests.Integration/Scripts/MSAccessBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/MSAccessBuildDatabase.sql index 63259fbd..dc573b70 100644 --- a/PetaPoco.Tests.Integration/Scripts/MSAccessBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/MSAccessBuildDatabase.sql @@ -131,3 +131,15 @@ CREATE TABLE BugInvestigation_5TN5C4U4 ( [ColumnA] TEXT(20), [Column2] TEXT(20) ); + +DROP TABLE [BugInvestigation_ISSUE178]; + +CREATE TABLE BugInvestigation_ISSUE178 ( + [Id] AUTOINCREMENT PRIMARY KEY, + [PersonId] TEXT(36) NOT NULL, + [PoNumber] TEXT(15) NOT NULL, + [OrderStatus] INTEGER NOT NULL, + [CreatedOn] DATETIME NOT NULL, + [CreatedBy] TEXT(255) NOT NULL, + [UpdatedAt] DATETIME +); diff --git a/PetaPoco.Tests.Integration/Scripts/MariaDBBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/MariaDBBuildDatabase.sql index bf8b67e3..65eae23b 100644 --- a/PetaPoco.Tests.Integration/Scripts/MariaDBBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/MariaDBBuildDatabase.sql @@ -107,6 +107,32 @@ CREATE TABLE `BugInvestigation_5TN5C4U4` ( `Column2` VARCHAR(20) ) ENGINE=INNODB; +DROP TABLE IF EXISTS BugInvestigation_ISSUE178; + +CREATE TABLE BugInvestigation_ISSUE178 ( + `Id` INT AUTO_INCREMENT PRIMARY KEY, + `PersonId` CHAR(36) NOT NULL, + `PoNumber` VARCHAR(15) NOT NULL, + `OrderStatus` INT NOT NULL, + `CreatedOn` DATETIME NOT NULL, + `CreatedBy` VARCHAR(255) NOT NULL, + `UpdatedAt` DATETIME NULL +) ENGINE=INNODB; + +CREATE TRIGGER Trigger_BugInvestigation_ISSUE178_UpdatedAt + BEFORE UPDATE ON BugInvestigation_ISSUE178 + FOR EACH ROW +BEGIN + SET NEW.UpdatedAt = NOW(); +END; + +CREATE TRIGGER Trigger_BugInvestigation_ISSUE178_UpdatedAtInsert + BEFORE INSERT ON BugInvestigation_ISSUE178 + FOR EACH ROW +BEGIN + SET NEW.UpdatedAt = NOW(); +END; + -- Stored Procedures DROP PROCEDURE IF EXISTS `SelectPeople`; diff --git a/PetaPoco.Tests.Integration/Scripts/MySqlBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/MySqlBuildDatabase.sql index bf8b67e3..51bf91fe 100644 --- a/PetaPoco.Tests.Integration/Scripts/MySqlBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/MySqlBuildDatabase.sql @@ -107,6 +107,18 @@ CREATE TABLE `BugInvestigation_5TN5C4U4` ( `Column2` VARCHAR(20) ) ENGINE=INNODB; +DROP TABLE IF EXISTS `BugInvestigation_ISSUE178`; + +CREATE TABLE `BugInvestigation_ISSUE178` ( + `Id` INT AUTO_INCREMENT PRIMARY KEY, + `PersonId` CHAR(36) NOT NULL, + `PoNumber` VARCHAR(15) NOT NULL, + `OrderStatus` INT NOT NULL, + `CreatedOn` DATETIME(6) NOT NULL, + `CreatedBy` VARCHAR(255) NOT NULL, + `UpdatedAt` DATETIME(6) NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP(6) +) ENGINE=INNODB; + -- Stored Procedures DROP PROCEDURE IF EXISTS `SelectPeople`; diff --git a/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql index b5c12382..b7ba2e0d 100644 --- a/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/PostgresBuildDatabase.sql @@ -123,6 +123,31 @@ CREATE TABLE "BugInvestigation_5TN5C4U4" ( "Column2" VARCHAR(20) ); +DROP TABLE IF EXISTS "BugInvestigation_ISSUE178"; + +CREATE TABLE "BugInvestigation_ISSUE178" ( + "Id" SERIAL PRIMARY KEY, + "PersonId" UUID NOT NULL, + "PoNumber" VARCHAR(15) NOT NULL, + "OrderStatus" INTEGER NOT NULL, + "CreatedOn" TIMESTAMP NOT NULL, + "CreatedBy" VARCHAR(255) NOT NULL, + "UpdatedAt" TIMESTAMP NULL +); + +CREATE OR REPLACE FUNCTION update_buginvestigation_issue178_updatedat() +RETURNS TRIGGER AS $$ +BEGIN + NEW."UpdatedAt" := NOW(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER trigger_buginvestigation_issue178_updatedat +BEFORE INSERT OR UPDATE ON "BugInvestigation_ISSUE178" +FOR EACH ROW +EXECUTE FUNCTION update_buginvestigation_issue178_updatedat(); + -- Stored Procedures CREATE FUNCTION SelectPeople() diff --git a/PetaPoco.Tests.Integration/Scripts/SQLiteBuildDatabase.sql b/PetaPoco.Tests.Integration/Scripts/SQLiteBuildDatabase.sql index 9b6ee2ba..6df07252 100644 --- a/PetaPoco.Tests.Integration/Scripts/SQLiteBuildDatabase.sql +++ b/PetaPoco.Tests.Integration/Scripts/SQLiteBuildDatabase.sql @@ -104,3 +104,31 @@ CREATE TABLE BugInvestigation_5TN5C4U4 ( [ColumnA] TEXT, [Column2] TEXT ); + +DROP TABLE IF EXISTS BugInvestigation_ISSUE178; + +CREATE TABLE BugInvestigation_ISSUE178 ( + [Id] INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, + [PersonId] TEXT NOT NULL, + [PoNumber] TEXT NOT NULL, + [OrderStatus] INTEGER NOT NULL, + [CreatedOn] INTEGER NOT NULL, + [CreatedBy] TEXT NOT NULL, + [UpdatedAt] DATETIME +); + +CREATE TRIGGER Trigger_BugInvestigation_ISSUE178_UpdatedAt + AFTER INSERT ON BugInvestigation_ISSUE178 +BEGIN + UPDATE BugInvestigation_ISSUE178 + SET UpdatedAt = CURRENT_TIMESTAMP + WHERE Id = NEW.Id; +END; + +CREATE TRIGGER Trigger_BugInvestigation_ISSUE178_UpdatedAt_Update + AFTER UPDATE ON BugInvestigation_ISSUE178 +BEGIN + UPDATE BugInvestigation_ISSUE178 + SET UpdatedAt = CURRENT_TIMESTAMP + WHERE Id = NEW.Id; +END;