From 6a818ee5d503638f2e3355405b4f912e2cfbd0b5 Mon Sep 17 00:00:00 2001 From: David Rogers Date: Mon, 4 Mar 2024 17:30:36 -0600 Subject: [PATCH] feat(QueryBuilder): Implement crossApply and outerApply for supported Grammars Supported Grammars include `SqlServerGrammar`, `MySQLGrammar`, `PostgresGrammar`, and `OracleGrammar`. --- models/Grammars/BaseGrammar.cfc | 58 +++++++++++++-- models/Grammars/SqlServerGrammar.cfc | 33 +++++++++ models/Query/JoinClause.cfc | 22 +++++- models/Query/QueryBuilder.cfc | 66 +++++++++++++++-- tests/resources/AbstractQueryBuilderSpec.cfc | 70 +++++++++++++++++++ tests/specs/Query/Abstract/JoinClauseSpec.cfc | 2 +- tests/specs/Query/MySQLQueryBuilderSpec.cfc | 16 +++++ tests/specs/Query/OracleQueryBuilderSpec.cfc | 16 +++++ .../specs/Query/PostgresQueryBuilderSpec.cfc | 16 +++++ tests/specs/Query/SQLiteQueryBuilderSpec.cfc | 16 +++++ .../specs/Query/SqlServerQueryBuilderSpec.cfc | 28 ++++++++ 11 files changed, 327 insertions(+), 16 deletions(-) diff --git a/models/Grammars/BaseGrammar.cfc b/models/Grammars/BaseGrammar.cfc index 7e252948..6b2983be 100644 --- a/models/Grammars/BaseGrammar.cfc +++ b/models/Grammars/BaseGrammar.cfc @@ -273,13 +273,57 @@ component displayname="Grammar" accessors="true" singleton { */ private string function compileJoins( required QueryBuilder query, required array joins ) { var joinsArray = []; + + if ( arguments.joins.isEmpty() ) { + return ""; + } + for ( var join in arguments.joins ) { - var conditions = compileWheres( join, join.getWheres() ); - var table = wrapTable( join.getTable() ); - joinsArray.append( "#uCase( join.getType() )# JOIN #table# #conditions#" ); + var joinFunc = variables[ "compile#replace( join.getType(), " ", "", "all" )#join" ]; + joinsArray.append( joinFunc( arguments.query, join ) ); } - return arrayToList( joinsArray, " " ); + if ( joinsArray.isEmpty() ) { + return ""; + } + + return joinsArray.toList( " " ); + } + + private string function compileInnerJoin( required QueryBuilder query, required JoinClause join ) { + var conditions = compileWheres( arguments.join, arguments.join.getWheres() ); + var table = wrapTable( arguments.join.getTable() ); + return "INNER JOIN #table# #conditions#"; + } + + private string function compileLeftJoin( required QueryBuilder query, required JoinClause join ) { + var conditions = compileWheres( arguments.join, arguments.join.getWheres() ); + var table = wrapTable( arguments.join.getTable() ); + return "LEFT JOIN #table# #conditions#"; + } + + private string function compileRightJoin( required QueryBuilder query, required JoinClause join ) { + var conditions = compileWheres( arguments.join, arguments.join.getWheres() ); + var table = wrapTable( arguments.join.getTable() ); + return "RIGHT JOIN #table# #conditions#"; + } + + private string function compileCrossJoin( required QueryBuilder query, required JoinClause join ) { + var conditions = compileWheres( arguments.join, arguments.join.getWheres() ); + var table = wrapTable( arguments.join.getTable() ); + return "CROSS JOIN #table# #conditions#"; + } + + private string function compileOuterApplyJoin( required QueryBuilder query, required JoinClause join ) { + throw( type = "UnsupportedOperation", message = "This grammar does not support OUTER APPLY joins" ); + } + + private string function compileCrossApplyJoin( required QueryBuilder query, required JoinClause join ) { + throw( type = "UnsupportedOperation", message = "This grammar does not support CROSS APPLY joins" ); + } + + private string function compileLateralJoin( required QueryBuilder query, required JoinClause join ) { + throw( type = "UnsupportedOperation", message = "This grammar does not support LATERAL joins" ); } /** @@ -1215,7 +1259,7 @@ component displayname="Grammar" accessors="true" singleton { function compileDropAllObjects() { throw( - type = "OperationNotSupported", + type = "UnsupportedOperation", message = "This database grammar does not support this operation", detail = "compileDropAllObjects" ); @@ -1223,7 +1267,7 @@ component displayname="Grammar" accessors="true" singleton { function compileEnableForeignKeyConstraints() { throw( - type = "OperationNotSupported", + type = "UnsupportedOperation", message = "This database grammar does not support this operation", detail = "compileEnableForeignKeyConstraints" ); @@ -1231,7 +1275,7 @@ component displayname="Grammar" accessors="true" singleton { function compileDisableForeignKeyConstraints() { throw( - type = "OperationNotSupported", + type = "UnsupportedOperation", message = "This database grammar does not support this operation", detail = "compileDisableForeignKeyConstraints" ); diff --git a/models/Grammars/SqlServerGrammar.cfc b/models/Grammars/SqlServerGrammar.cfc index cb0300d1..d7b338ad 100644 --- a/models/Grammars/SqlServerGrammar.cfc +++ b/models/Grammars/SqlServerGrammar.cfc @@ -83,6 +83,39 @@ component extends="qb.models.Grammars.BaseGrammar" singleton accessors="true" { ); } + private string function compileOuterApplyJoin( required QueryBuilder query, required JoinClause join ) { + // OUTER APPLY ( ) (AS)? + var tableName = wrapTable( join.getTable() ) + if ( !reFindNoCase( "^\s*#trim( getTableAliasOperator() )#", tableName ) ) { + // table alias operator is optional in MSSqlServer, but we'll provide it if it wasn't expanded via wrapTable. + // Will `wrapTable` ever have emitted a table alias operator here? + // n.b. `getTableAliasOperator()` is expected to have a leading and trailing space. + tableName = "#getTableAliasOperator()##tableName#"; + } + // `tableName` is expected to have at least a leading space. + return "OUTER APPLY (#join.getLateralRawExpression()#)#tableName#"; + } + + private string function compileCrossApplyJoin( required QueryBuilder query, required JoinClause join ) { + // CROSS APPLY ( ) (AS)? + var tableName = wrapTable( join.getTable() ) + if ( !reFindNoCase( "^\s*#trim( getTableAliasOperator() )#", tableName ) ) { + // table alias operator is optional in MSSqlServer, but we'll provide it if it wasn't expanded via wrapTable. + // Will `wrapTable` ever have emitted a table alias operator here? + // n.b. `getTableAliasOperator()` is expected to have a leading and trailing space. + tableName = "#getTableAliasOperator()##tableName#"; + } + // `tableName` is expected to have at least a leading space. + return "CROSS APPLY (#join.getLateralRawExpression()#)#tableName#"; + } + + private string function compileLateralJoin( required QueryBuilder query, required JoinClause join ) { + throw( + type = "UnsupportedOperation", + message = "This grammar does not support LATERAL joins. Instead, use either OUTER APPLY or CROSS APPLY joins." + ); + } + /** * Compiles the Common Table Expressions (CTEs). * diff --git a/models/Query/JoinClause.cfc b/models/Query/JoinClause.cfc index a8fc1287..92da5c6c 100644 --- a/models/Query/JoinClause.cfc +++ b/models/Query/JoinClause.cfc @@ -18,6 +18,12 @@ component displayname="JoinClause" accessors="true" extends="qb.models.Query.Que */ property name="table" type="any"; + /** + * In the {cross,outer}Apply case, the already-toSql'd string of the table expr source. + * e.g. will be a string like "select 1 from foo where x = ?" + */ + property name="lateralRawExpression" type="string"; + /** * Valid join types for join clauses. */ @@ -28,7 +34,10 @@ component displayname="JoinClause" accessors="true" extends="qb.models.Query.Que "left", "left outer", "right", - "right outer" + "right outer", + "outer apply", + "cross apply", + "lateral" ]; /** @@ -37,10 +46,16 @@ component displayname="JoinClause" accessors="true" extends="qb.models.Query.Que * @parentQuery A reference to the query to which this join clause belongs. * @type The join type of this join clause. * @table The table to join. + * @crossApplySqlStringWithBindParams The already-`toSql`'d table expression for the {cross,outer}Apply case * * @return qb.models.Query.JoinClause */ - public JoinClause function init( required QueryBuilder parentQuery, required string type, required any table ) { + public JoinClause function init( + required QueryBuilder parentQuery, + required string type, + required any table, + string lateralRawExpression + ) { var typeIsValid = false; for ( var validType in variables.types ) { if ( validType == arguments.type ) { @@ -54,6 +69,9 @@ component displayname="JoinClause" accessors="true" extends="qb.models.Query.Que variables.parentQuery = arguments.parentQuery; variables.type = arguments.type; variables.table = arguments.table; + variables.lateralRawExpression = isNull( arguments.lateralRawExpression ) + ? "" + : arguments.lateralRawExpression; super.init( parentQuery.getGrammar(), parentQuery.getUtils() ); diff --git a/models/Query/QueryBuilder.cfc b/models/Query/QueryBuilder.cfc index 04b26573..4791e919 100644 --- a/models/Query/QueryBuilder.cfc +++ b/models/Query/QueryBuilder.cfc @@ -1016,6 +1016,63 @@ component displayname="QueryBuilder" accessors="true" { return joinRaw( argumentCollection = arguments ); } + private function outerOrCrossApply( required string name, required string type, required tableLikeSource ) { + if ( type != "outer apply" && type != "cross apply" && type != "lateral" ) { + throw( + type = "QBInvalidJoinType", + message = "Invalid join type: #arguments.type#. Valid types are [`outer apply`, `cross apply`, or `lateral`]" + ); + } + + var sourceIsBuilder = getUtils().isBuilder( arguments.tableLikeSource ) + var sourceIsFunc = isClosure( arguments.tableLikeSource ) || isCustomFunction( arguments.tableLikeSource ) + + if ( !sourceIsBuilder && !sourceIsFunc ) { + throw( + type = "QBInvalidJoinSource", + message = "Invalid join source. Valid types are a QueryBuilder instance or a callback function that receives a new QueryBuilder instance." + ); + } + + if ( sourceIsFunc ) { + var subquery = newQuery(); + arguments.tableLikeSource( subquery ); + arguments.tableLikeSource = subquery; + } + + var join = new qb.models.Query.JoinClause( + parentQuery = this, + type = type, + table = arguments.name, + lateralRawExpression = arguments.tableLikeSource.toSQL() + ); + + if ( this.getPreventDuplicateJoins() ) { + var hasThisJoin = variables.joins.find( function( existingJoin ) { + return existingJoin.isEqualTo( join ); + } ); + + if ( hasThisJoin ) { + // Do nothing, early return + // We have not mutated `this` in any way. + return this; + } + } + + addBindings( tableLikeSource.getBindings(), "join" ); + variables.joins.append( join ); + + return this; + } + + public function outerApply( required string name, required any tableDef ) { + return outerOrCrossApply( name = name, type = "outer apply", tableLikeSource = tableDef ); + } + + public function crossApply( required string name, required any tableDef ) { + return outerOrCrossApply( name = name, type = "cross apply", tableLikeSource = tableDef ); + } + /** * Adds a LEFT JOIN from a derived table to another table. * @@ -3079,10 +3136,9 @@ component displayname="QueryBuilder" accessors="true" { } /** - * Adds a single binding or an array of bindings to a query for a given type. + * Adds all of the bindings from another builder instance. * - * @newBindings A single binding or an array of bindings to add for a given type. - * @type The type of binding to add. + * @qb Another builder instance to copy all of the bindings from. * * @return qb.models.Query.QueryBuilder */ @@ -3248,9 +3304,7 @@ component displayname="QueryBuilder" accessors="true" { * If no records exist, it throws an RecordNotFound exception. * * @options Any options to pass to `queryExecute`. Default: {}. - * @errorMessage An optional string error message or callback to produce - * a string error message. If a callback is used, it is - * passed the unloaded entity as the only argument. + * @errorMessage An optional string error message. * * @throws RecordNotFound * diff --git a/tests/resources/AbstractQueryBuilderSpec.cfc b/tests/resources/AbstractQueryBuilderSpec.cfc index 4f9a9fbf..4c30177a 100644 --- a/tests/resources/AbstractQueryBuilderSpec.cfc +++ b/tests/resources/AbstractQueryBuilderSpec.cfc @@ -1306,6 +1306,76 @@ component extends="testbox.system.BaseSpec" { .where( "A.C", "=", "C" ); }, joinSubBindings() ); } ); + + it( "can cross apply", function() { + testCase( function( builder ) { + builder + .from( "users as u" ) + .crossApply( "childCount", function( qb ) { + qb.selectRaw( "count(*) c" ) + .from( "children" ) + .whereColumn( "children.parentID", "=", "users.ID" ) + .where( "children.someCol", "=", 0 ) + } ) + .select( [ "u.ID", "childCount.c" ] ) + .where( "childCount.c", ">", 1 ) + }, crossApply() ); + } ); + + it( "can outer apply", function() { + testCase( function( builder ) { + builder + .from( "users as u" ) + .outerApply( "childCount", function( qb ) { + qb.selectRaw( "count(*) c" ) + .from( "children" ) + .whereColumn( "children.parentID", "=", "users.ID" ) + .where( "children.someCol", "=", 0 ) + } ) + .select( [ "u.ID", "childCount.c" ] ) + .where( "childCount.c", ">", 1 ) + }, outerApply() ); + } ); + + it( "correctly positions bindings using crossApply", function() { + testCase( function( builder ) { + builder + .from( "A" ) + .where( "A.A", "=", "A" ) + .crossApply( + "B", + getBuilder() + .from( "x" ) + .where( "x.x", "=", "B" ) + .whereColumn( "x.b", "=", "a.b" ) + ) + .where( "A.C", "=", "C" ) + .outerApply( "D", ( qb ) => { + qb.from( "y" ) + .where( "y.y", "=", "D" ) + .whereColumn( "y.d", "=", "a.d" ) + } ) + }, correctlyPositionsBindingsUsingCrossApply() ); + } ); + + it( "duplicate {cross,outer} applies eliminated", function() { + testCase( function( builder ) { + var gen = ( name ) => ( qb ) => { + qb.from( name ).select( "someColumn" ) + } + builder + .setPreventDuplicateJoins( true ) + .from( "A" ) + .crossApply( "B", gen( "crossapply_B" ) ) + .outerApply( "C", gen( "outerapply_C" ) ) + .crossApply( "B", gen( "crossapply_B" ) ) + .outerApply( "C", gen( "outerapply_C" ) ) + .crossApply( "D", gen( "crossapply_D" ) ) + .outerApply( "E", gen( "outerapply_E" ) ) + .crossApply( "D", gen( "crossapply_D" ) ) + .outerApply( "E", gen( "outerapply_E" ) ) + }, duplicateCrossAndOuterAppliesEliminated() ); + } ); } ); describe( "group bys", function() { diff --git a/tests/specs/Query/Abstract/JoinClauseSpec.cfc b/tests/specs/Query/Abstract/JoinClauseSpec.cfc index c5c58bfd..920d702e 100644 --- a/tests/specs/Query/Abstract/JoinClauseSpec.cfc +++ b/tests/specs/Query/Abstract/JoinClauseSpec.cfc @@ -191,7 +191,7 @@ component extends="testbox.system.BaseSpec" { describe( "getMementoForComparison", function() { beforeEach( function() { variables.qb = new qb.models.Query.QueryBuilder( preventDuplicateJoins = true ).from( - new qb.models.Query.QueryBuilder( preventDuplicateJOins = true ) + new qb.models.Query.QueryBuilder( preventDuplicateJoins = true ) .select( "FK_otherTable" ) .from( "second_table" ) ); diff --git a/tests/specs/Query/MySQLQueryBuilderSpec.cfc b/tests/specs/Query/MySQLQueryBuilderSpec.cfc index b2c7ab45..22fa04a4 100644 --- a/tests/specs/Query/MySQLQueryBuilderSpec.cfc +++ b/tests/specs/Query/MySQLQueryBuilderSpec.cfc @@ -1000,4 +1000,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return builder; } + function crossApply() { + return { exception: "UnsupportedOperation" } + } + + function outerApply() { + return { exception: "UnsupportedOperation" } + } + + function correctlyPositionsBindingsUsingCrossApply() { + return { exception: "UnsupportedOperation" } + } + + function duplicateCrossAndOuterAppliesEliminated() { + return { exception: "UnsupportedOperation" } + } + } diff --git a/tests/specs/Query/OracleQueryBuilderSpec.cfc b/tests/specs/Query/OracleQueryBuilderSpec.cfc index f2a972e1..6ffba233 100644 --- a/tests/specs/Query/OracleQueryBuilderSpec.cfc +++ b/tests/specs/Query/OracleQueryBuilderSpec.cfc @@ -1016,4 +1016,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return builder; } + function crossApply() { + return { exception: "UnsupportedOperation" } + } + + function outerApply() { + return { exception: "UnsupportedOperation" } + } + + function correctlyPositionsBindingsUsingCrossApply() { + return { exception: "UnsupportedOperation" } + } + + function duplicateCrossAndOuterAppliesEliminated() { + return { exception: "UnsupportedOperation" } + } + } diff --git a/tests/specs/Query/PostgresQueryBuilderSpec.cfc b/tests/specs/Query/PostgresQueryBuilderSpec.cfc index bf848632..d2b676d5 100644 --- a/tests/specs/Query/PostgresQueryBuilderSpec.cfc +++ b/tests/specs/Query/PostgresQueryBuilderSpec.cfc @@ -1031,4 +1031,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return builder; } + function crossApply() { + return { exception: "UnsupportedOperation" } + } + + function outerApply() { + return { exception: "UnsupportedOperation" } + } + + function correctlyPositionsBindingsUsingCrossApply() { + return { exception: "UnsupportedOperation" } + } + + function duplicateCrossAndOuterAppliesEliminated() { + return { exception: "UnsupportedOperation" } + } + } diff --git a/tests/specs/Query/SQLiteQueryBuilderSpec.cfc b/tests/specs/Query/SQLiteQueryBuilderSpec.cfc index 71fc0b0e..781a1e68 100644 --- a/tests/specs/Query/SQLiteQueryBuilderSpec.cfc +++ b/tests/specs/Query/SQLiteQueryBuilderSpec.cfc @@ -1031,4 +1031,20 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { }; } + function crossApply() { + return { exception: "UnsupportedOperation" } + } + + function outerApply() { + return { exception: "UnsupportedOperation" } + } + + function correctlyPositionsBindingsUsingCrossApply() { + return { exception: "UnsupportedOperation" } + } + + function duplicateCrossAndOuterAppliesEliminated() { + return { exception: "UnsupportedOperation" } + } + } diff --git a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc index fa40beeb..8924aff2 100644 --- a/tests/specs/Query/SqlServerQueryBuilderSpec.cfc +++ b/tests/specs/Query/SqlServerQueryBuilderSpec.cfc @@ -1009,6 +1009,34 @@ component extends="tests.resources.AbstractQueryBuilderSpec" { return "SELECT * FROM [otherTable]"; } + function crossApply() { + return { + sql: "SELECT [u].[ID], [childCount].[c] FROM [users] AS [u] CROSS APPLY (SELECT count(*) c FROM [children] WHERE [children].[parentID] = [users].[ID] AND [children].[someCol] = ?) AS [childCount] WHERE [childCount].[c] > ?", + bindings: [ 0, 1 ] + } + } + + function outerApply() { + return { + sql: "SELECT [u].[ID], [childCount].[c] FROM [users] AS [u] OUTER APPLY (SELECT count(*) c FROM [children] WHERE [children].[parentID] = [users].[ID] AND [children].[someCol] = ?) AS [childCount] WHERE [childCount].[c] > ?", + bindings: [ 0, 1 ] + } + } + + function correctlyPositionsBindingsUsingCrossApply() { + return { + sql: "SELECT * FROM [A] CROSS APPLY (SELECT * FROM [x] WHERE [x].[x] = ? AND [x].[b] = [a].[b]) AS [B] OUTER APPLY (SELECT * FROM [y] WHERE [y].[y] = ? AND [y].[d] = [a].[d]) AS [D] WHERE [A].[A] = ? AND [A].[C] = ?", + bindings: [ "B", "D", "A", "C" ] + }; + } + + function duplicateCrossAndOuterAppliesEliminated() { + return { + sql: "SELECT * FROM [A] CROSS APPLY (SELECT [someColumn] FROM [crossapply_B]) AS [B] OUTER APPLY (SELECT [someColumn] FROM [outerapply_C]) AS [C] CROSS APPLY (SELECT [someColumn] FROM [crossapply_D]) AS [D] OUTER APPLY (SELECT [someColumn] FROM [outerapply_E]) AS [E]", + bindings: [] + }; + } + private function getBuilder() { variables.utils = getMockBox().createMock( "qb.models.Query.QueryUtils" ).init(); variables.grammar = getMockBox().createMock( "qb.models.Grammars.SqlServerGrammar" ).init( variables.utils );