Skip to content

Commit

Permalink
fix(BaseGrammar): Detect column aliases in raw statements
Browse files Browse the repository at this point in the history
This is used in conjunction with deriving column names for
`insertUsing` statements.  With this change, the alias
for raw statements can also be derived.  Raw statements
without an alias will not be processed and will result in
an invalid query. In those cases, either an alias can be
added or the `columns` can be explicitly defined.
  • Loading branch information
elpete committed Aug 5, 2022
1 parent 3858dd5 commit 727f777
Show file tree
Hide file tree
Showing 6 changed files with 46 additions and 2 deletions.
4 changes: 2 additions & 2 deletions models/Grammars/BaseGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -982,7 +982,7 @@ component displayname="Grammar" accessors="true" singleton {
isObject( arguments.column ) &&
structKeyExists( arguments.column, "getSQL" )
) {
return trim( arguments.column.getSQL() );
arguments.column = trim( arguments.column.getSQL() );
}

arguments.column = trim( arguments.column );
Expand All @@ -998,7 +998,7 @@ component displayname="Grammar" accessors="true" singleton {
return mid( arguments.column, matches.pos[ 3 ], matches.len[ 3 ] );
}
} else if ( arguments.column.findNoCase( " " ) > 0 ) {
return listGetAt( arguments.column, 2, " " );
return listLast( arguments.column, " " );
}

return listLast( arguments.column, "." );
Expand Down
16 changes: 16 additions & 0 deletions tests/resources/AbstractQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -2124,6 +2124,22 @@ component extends="testbox.system.BaseSpec" {
}, insertUsingDerivingColumnNames() );
} );

it( "can guess column names from raw statements in an insert using query", function() {
testCase( function( builder ) {
return builder
.from( "users" )
.insertUsing(
source = function( q ) {
q.from( "activeDirectoryUsers" )
.select( "email" )
.selectRaw( "COALESCE(modifiedDate, NOW()) AS createdDate" )
.where( "active", 1 );
},
toSql = true
);
}, insertUsingDerivedColumnNamesFromRawStatements() );
} );

it( "can insert ignoring conflicts", function() {
testCase( function( builder ) {
return builder
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/MySQLQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -673,6 +673,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function insertUsingDerivedColumnNamesFromRawStatements() {
return {
sql: "INSERT INTO `users` (`email`, `createdDate`) SELECT `email`, COALESCE(modifiedDate, NOW()) AS createdDate FROM `activeDirectoryUsers` WHERE `active` = ?",
bindings: [ 1 ]
};
}

function insertIgnore() {
return {
sql: "INSERT IGNORE INTO `users` (`email`, `name`) VALUES (?, ?), (?, ?)",
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/OracleQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -686,6 +686,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function insertUsingDerivedColumnNamesFromRawStatements() {
return {
SQL: "INSERT INTO ""USERS"" (""EMAIL"", ""CREATEDDATE"") SELECT ""EMAIL"", COALESCE(modifiedDate, NOW()) AS createdDate FROM ""ACTIVEDIRECTORYUSERS"" WHERE ""ACTIVE"" = ?",
bindings: [ 1 ]
};
}

function insertIgnore() {
return {
sql: "MERGE INTO ""USERS"" ""QB_TARGET"" USING (SELECT ?, ? FROM dual UNION ALL SELECT ?, ? FROM dual) ""QB_SRC"" ON ""QB_TARGET"".""EMAIL"" = ""QB_SRC"".""EMAIL"" WHEN NOT MATCHED THEN INSERT (""EMAIL"", ""NAME"") VALUES (""QB_SRC"".""EMAIL"", ""QB_SRC"".""NAME"")",
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/PostgresQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -680,6 +680,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function insertUsingDerivedColumnNamesFromRawStatements() {
return {
sql: "INSERT INTO ""users"" (""email"", ""createdDate"") SELECT ""email"", COALESCE(modifiedDate, NOW()) AS createdDate FROM ""activeDirectoryUsers"" WHERE ""active"" = ?",
bindings: [ 1 ]
};
}

function insertIgnore() {
return {
sql: "INSERT INTO ""users"" (""email"", ""name"") VALUES (?, ?), (?, ?) ON CONFLICT DO NOTHING",
Expand Down
7 changes: 7 additions & 0 deletions tests/specs/Query/SqlServerQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -674,6 +674,13 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function insertUsingDerivedColumnNamesFromRawStatements() {
return {
sql: "INSERT INTO [users] ([email], [createdDate]) SELECT [email], COALESCE(modifiedDate, NOW()) AS createdDate FROM [activeDirectoryUsers] WHERE [active] = ?",
bindings: [ 1 ]
};
}

function insertIgnore() {
return {
sql: "MERGE [users] AS [qb_target] USING (VALUES (?, ?), (?, ?)) AS [qb_src] ([email], [name]) ON [qb_target].[email] = [qb_src].[email] WHEN NOT MATCHED BY TARGET THEN INSERT ([email], [name]) VALUES ([email], [name]);",
Expand Down

0 comments on commit 727f777

Please sign in to comment.