Skip to content

Commit

Permalink
fix(QueryBuilder): Maintain column order when using source in upsert
Browse files Browse the repository at this point in the history
  • Loading branch information
elpete committed Jun 14, 2022
1 parent 6238626 commit c44e626
Show file tree
Hide file tree
Showing 6 changed files with 37 additions and 15 deletions.
8 changes: 5 additions & 3 deletions models/Query/QueryBuilder.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -2784,9 +2784,11 @@ component displayname="QueryBuilder" accessors="true" {
var formatted = listLast( applyColumnFormatter( column ), "." );
return { "original": column, "formatted": formatted };
} );
columns.sort( function( a, b ) {
return compareNoCase( a.formatted, b.formatted );
} );
if ( isStruct( arguments.values[ 1 ] ) ) {
columns.sort( function( a, b ) {
return compareNoCase( a.formatted, b.formatted );
} );
}

var updateArray = [];
if ( isNull( arguments.update ) ) {
Expand Down
26 changes: 23 additions & 3 deletions tests/resources/AbstractQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -2323,7 +2323,13 @@ component extends="testbox.system.BaseSpec" {
.table( "users" )
.upsert(
source = function( q ) {
q.from( "activeDirectoryUsers" );
q.from( "activeDirectoryUsers" )
.select( [
"username",
"active",
"createdDate",
"modifiedDate"
] );
},
values = [
"username",
Expand All @@ -2343,7 +2349,15 @@ component extends="testbox.system.BaseSpec" {
return builder
.table( "users" )
.upsert(
source = builder.newQuery().from( "activeDirectoryUsers" ),
source = builder
.newQuery()
.from( "activeDirectoryUsers" )
.select( [
"username",
"active",
"createdDate",
"modifiedDate"
] ),
values = [
"username",
"active",
Expand All @@ -2363,7 +2377,13 @@ component extends="testbox.system.BaseSpec" {
.table( "users" )
.upsert(
source = function( q ) {
q.from( "activeDirectoryUsers" );
q.from( "activeDirectoryUsers" )
.select( [
"username",
"active",
"createdDate",
"modifiedDate"
] );
},
values = [
"username",
Expand Down
4 changes: 2 additions & 2 deletions tests/specs/Query/MySQLQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -783,14 +783,14 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {

function upsertFromClosure() {
return {
sql: "INSERT INTO `users` (`active`, `createdDate`, `modifiedDate`, `username`) SELECT * FROM `activeDirectoryUsers` ON DUPLICATE KEY UPDATE `active` = VALUES(`active`), `modifiedDate` = VALUES(`modifiedDate`)",
sql: "INSERT INTO `users` (`username`, `active`, `createdDate`, `modifiedDate`) SELECT `username`, `active`, `createdDate`, `modifiedDate` FROM `activeDirectoryUsers` ON DUPLICATE KEY UPDATE `active` = VALUES(`active`), `modifiedDate` = VALUES(`modifiedDate`)",
bindings: []
};
}

function upsertFromBuilder() {
return {
sql: "INSERT INTO `users` (`active`, `createdDate`, `modifiedDate`, `username`) SELECT * FROM `activeDirectoryUsers` ON DUPLICATE KEY UPDATE `active` = VALUES(`active`), `modifiedDate` = VALUES(`modifiedDate`)",
sql: "INSERT INTO `users` (`username`, `active`, `createdDate`, `modifiedDate`) SELECT `username`, `active`, `createdDate`, `modifiedDate` FROM `activeDirectoryUsers` ON DUPLICATE KEY UPDATE `active` = VALUES(`active`), `modifiedDate` = VALUES(`modifiedDate`)",
bindings: []
};
}
Expand Down
4 changes: 2 additions & 2 deletions tests/specs/Query/OracleQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -799,14 +799,14 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {

function upsertFromClosure() {
return {
sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT * FROM ""ACTIVEDIRECTORYUSERS"") ""QB_SRC"" ON ""QB_TARGET"".""USERNAME"" = ""QB_SRC"".""USERNAME"" WHEN MATCHED THEN UPDATE SET ""ACTIVE"" = ""QB_SRC"".""ACTIVE"", ""MODIFIEDDATE"" = ""QB_SRC"".""MODIFIEDDATE"" WHEN NOT MATCHED THEN INSERT (""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"", ""USERNAME"") VALUES (""QB_SRC"".""ACTIVE"", ""QB_SRC"".""CREATEDDATE"", ""QB_SRC"".""MODIFIEDDATE"", ""QB_SRC"".""USERNAME"")",
sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT ""USERNAME"", ""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"" FROM ""ACTIVEDIRECTORYUSERS"") ""QB_SRC"" ON ""QB_TARGET"".""USERNAME"" = ""QB_SRC"".""USERNAME"" WHEN MATCHED THEN UPDATE SET ""ACTIVE"" = ""QB_SRC"".""ACTIVE"", ""MODIFIEDDATE"" = ""QB_SRC"".""MODIFIEDDATE"" WHEN NOT MATCHED THEN INSERT (""USERNAME"", ""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"") VALUES (""QB_SRC"".""USERNAME"", ""QB_SRC"".""ACTIVE"", ""QB_SRC"".""CREATEDDATE"", ""QB_SRC"".""MODIFIEDDATE"")",
bindings: []
};
}

function upsertFromBuilder() {
return {
sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT * FROM ""ACTIVEDIRECTORYUSERS"") ""QB_SRC"" ON ""QB_TARGET"".""USERNAME"" = ""QB_SRC"".""USERNAME"" WHEN MATCHED THEN UPDATE SET ""ACTIVE"" = ""QB_SRC"".""ACTIVE"", ""MODIFIEDDATE"" = ""QB_SRC"".""MODIFIEDDATE"" WHEN NOT MATCHED THEN INSERT (""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"", ""USERNAME"") VALUES (""QB_SRC"".""ACTIVE"", ""QB_SRC"".""CREATEDDATE"", ""QB_SRC"".""MODIFIEDDATE"", ""QB_SRC"".""USERNAME"")",
sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT ""USERNAME"", ""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"" FROM ""ACTIVEDIRECTORYUSERS"") ""QB_SRC"" ON ""QB_TARGET"".""USERNAME"" = ""QB_SRC"".""USERNAME"" WHEN MATCHED THEN UPDATE SET ""ACTIVE"" = ""QB_SRC"".""ACTIVE"", ""MODIFIEDDATE"" = ""QB_SRC"".""MODIFIEDDATE"" WHEN NOT MATCHED THEN INSERT (""USERNAME"", ""ACTIVE"", ""CREATEDDATE"", ""MODIFIEDDATE"") VALUES (""QB_SRC"".""USERNAME"", ""QB_SRC"".""ACTIVE"", ""QB_SRC"".""CREATEDDATE"", ""QB_SRC"".""MODIFIEDDATE"")",
bindings: []
};
}
Expand Down
4 changes: 2 additions & 2 deletions tests/specs/Query/PostgresQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -799,14 +799,14 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {

function upsertFromClosure() {
return {
sql: "INSERT INTO ""users"" (""active"", ""createdDate"", ""modifiedDate"", ""username"") SELECT * FROM ""activeDirectoryUsers"" ON CONFLICT (""username"") DO UPDATE ""active"" = EXCLUDED.""active"", ""modifiedDate"" = EXCLUDED.""modifiedDate""",
sql: "INSERT INTO ""users"" (""username"", ""active"", ""createdDate"", ""modifiedDate"") SELECT ""username"", ""active"", ""createdDate"", ""modifiedDate"" FROM ""activeDirectoryUsers"" ON CONFLICT (""username"") DO UPDATE ""active"" = EXCLUDED.""active"", ""modifiedDate"" = EXCLUDED.""modifiedDate""",
bindings: []
};
}

function upsertFromBuilder() {
return {
sql: "INSERT INTO ""users"" (""active"", ""createdDate"", ""modifiedDate"", ""username"") SELECT * FROM ""activeDirectoryUsers"" ON CONFLICT (""username"") DO UPDATE ""active"" = EXCLUDED.""active"", ""modifiedDate"" = EXCLUDED.""modifiedDate""",
sql: "INSERT INTO ""users"" (""username"", ""active"", ""createdDate"", ""modifiedDate"") SELECT ""username"", ""active"", ""createdDate"", ""modifiedDate"" FROM ""activeDirectoryUsers"" ON CONFLICT (""username"") DO UPDATE ""active"" = EXCLUDED.""active"", ""modifiedDate"" = EXCLUDED.""modifiedDate""",
bindings: []
};
}
Expand Down
6 changes: 3 additions & 3 deletions tests/specs/Query/SqlServerQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -787,21 +787,21 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {

function upsertFromClosure() {
return {
sql: "MERGE [users] AS [qb_target] USING (SELECT * FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([active], [createdDate], [modifiedDate], [username]) VALUES ([active], [createdDate], [modifiedDate], [username]);",
sql: "MERGE [users] AS [qb_target] USING (SELECT [username], [active], [createdDate], [modifiedDate] FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([username], [active], [createdDate], [modifiedDate]) VALUES ([username], [active], [createdDate], [modifiedDate]);",
bindings: []
};
}

function upsertFromBuilder() {
return {
sql: "MERGE [users] AS [qb_target] USING (SELECT * FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([active], [createdDate], [modifiedDate], [username]) VALUES ([active], [createdDate], [modifiedDate], [username]);",
sql: "MERGE [users] AS [qb_target] USING (SELECT [username], [active], [createdDate], [modifiedDate] FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([username], [active], [createdDate], [modifiedDate]) VALUES ([username], [active], [createdDate], [modifiedDate]);",
bindings: []
};
}

function upsertWithDelete() {
return {
sql: "MERGE [users] AS [qb_target] USING (SELECT * FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([active], [createdDate], [modifiedDate], [username]) VALUES ([active], [createdDate], [modifiedDate], [username]) WHEN NOT MATCHED BY SOURCE DELETE;",
sql: "MERGE [users] AS [qb_target] USING (SELECT [username], [active], [createdDate], [modifiedDate] FROM [activeDirectoryUsers]) AS [qb_src] ON [qb_target].[username] = [qb_src].[username] WHEN MATCHED THEN UPDATE SET [active] = [qb_src].[active], [modifiedDate] = [qb_src].[modifiedDate] WHEN NOT MATCHED BY TARGET THEN INSERT ([username], [active], [createdDate], [modifiedDate]) VALUES ([username], [active], [createdDate], [modifiedDate]) WHEN NOT MATCHED BY SOURCE DELETE;",
bindings: []
};
}
Expand Down

0 comments on commit c44e626

Please sign in to comment.