Skip to content

Commit

Permalink
fix(QueryBuilder): Add compilations for all join types
Browse files Browse the repository at this point in the history
  • Loading branch information
elpete committed Mar 12, 2024
1 parent 1452359 commit 98e36a5
Show file tree
Hide file tree
Showing 9 changed files with 233 additions and 0 deletions.
24 changes: 24 additions & 0 deletions models/Grammars/BaseGrammar.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -296,18 +296,42 @@ component displayname="Grammar" accessors="true" singleton {
return "INNER JOIN #table# #conditions#";
}

private string function compileFullJoin( required QueryBuilder query, required JoinClause join ) {
var conditions = compileWheres( arguments.join, arguments.join.getWheres() );
var table = wrapTable( arguments.join.getTable() );
return "FULL JOIN #table# #conditions#";
}

private string function compileFullOuterJoin( required QueryBuilder query, required JoinClause join ) {
var conditions = compileWheres( arguments.join, arguments.join.getWheres() );
var table = wrapTable( arguments.join.getTable() );
return "FULL OUTER 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 compileLeftOuterJoin( required QueryBuilder query, required JoinClause join ) {
var conditions = compileWheres( arguments.join, arguments.join.getWheres() );
var table = wrapTable( arguments.join.getTable() );
return "LEFT OUTER 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 compileRightOuterJoin( required QueryBuilder query, required JoinClause join ) {
var conditions = compileWheres( arguments.join, arguments.join.getWheres() );
var table = wrapTable( arguments.join.getTable() );
return "RIGHT OUTER 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() );
Expand Down
1 change: 1 addition & 0 deletions models/Query/JoinClause.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,7 @@ component displayname="JoinClause" accessors="true" extends="qb.models.Query.Que
variables.types = [
"inner",
"full",
"full outer",
"cross",
"left",
"left outer",
Expand Down
104 changes: 104 additions & 0 deletions models/Query/QueryBuilder.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -798,6 +798,58 @@ component displayname="QueryBuilder" accessors="true" {
return this;
}

/**
* Adds a FULL JOIN to another table.
*
* For simple joins, this specifies a column on which to join the two tables.
* For complex joins, a closure can be passed to `first`.
* This allows multiple `on` and `where` conditions to be applied to the join.
*
* @table The table/expression to join to the query.
* @first The first column in the join's `on` statement. This alternatively can be a closure that will be passed a JoinClause for complex joins. Passing a closure ignores all subsequent parameters.
* @operator The boolean operator for the join clause. Default: "=".
* @second The second column in the join's `on` statement.
* @where Sets if the value of `second` should be interpreted as a column or a value. Passing this as an argument is discouraged. Use the dedicated `joinWhere` or a join closure where possible.
*
* @return qb.models.Query.QueryBuilder
*/
public QueryBuilder function fullJoin(
required any table,
any first,
string operator,
string second,
boolean where
) {
arguments.type = "full";
return join( argumentCollection = arguments );
}

/**
* Adds a FULL JOIN to another table.
*
* For simple joins, this specifies a column on which to join the two tables.
* For complex joins, a closure can be passed to `first`.
* This allows multiple `on` and `where` conditions to be applied to the join.
*
* @table The table/expression to join to the query.
* @first The first column in the join's `on` statement. This alternatively can be a closure that will be passed a JoinClause for complex joins. Passing a closure ignores all subsequent parameters.
* @operator The boolean operator for the join clause. Default: "=".
* @second The second column in the join's `on` statement.
* @where Sets if the value of `second` should be interpreted as a column or a value. Passing this as an argument is discouraged. Use the dedicated `joinWhere` or a join closure where possible.
*
* @return qb.models.Query.QueryBuilder
*/
public QueryBuilder function fullOuterJoin(
required any table,
any first,
string operator,
string second,
boolean where
) {
arguments.type = "full outer";
return join( argumentCollection = arguments );
}

/**
* Adds a LEFT JOIN to another table.
*
Expand All @@ -824,6 +876,32 @@ component displayname="QueryBuilder" accessors="true" {
return join( argumentCollection = arguments );
}

/**
* Adds a LEFT OUTER JOIN to another table.
*
* For simple joins, this specifies a column on which to join the two tables.
* For complex joins, a closure can be passed to `first`.
* This allows multiple `on` and `where` conditions to be applied to the join.
*
* @table The table/expression to join to the query.
* @first The first column in the join's `on` statement. This alternatively can be a closure that will be passed a JoinClause for complex joins. Passing a closure ignores all subsequent parameters.
* @operator The boolean operator for the join clause. Default: "=".
* @second The second column in the join's `on` statement.
* @where Sets if the value of `second` should be interpreted as a column or a value. Passing this as an argument is discouraged. Use the dedicated `joinWhere` or a join closure where possible.
*
* @return qb.models.Query.QueryBuilder
*/
public QueryBuilder function leftOuterJoin(
required any table,
any first,
string operator,
string second,
boolean where
) {
arguments.type = "left outer";
return join( argumentCollection = arguments );
}

/**
* Adds a RIGHT JOIN to another table.
*
Expand All @@ -850,6 +928,32 @@ component displayname="QueryBuilder" accessors="true" {
return join( argumentCollection = arguments );
}

/**
* Adds a RIGHT OUTER JOIN to another table.
*
* For simple joins, this specifies a column on which to join the two tables.
* For complex joins, a closure can be passed to `first`.
* This allows multiple `on` and `where` conditions to be applied to the join.
*
* @table The table/expression to join to the query.
* @first The first column in the join's `on` statement. This alternatively can be a closure that will be passed a JoinClause for complex joins. Passing a closure ignores all subsequent parameters.
* @operator The boolean operator for the join clause. Default: "=".
* @second The second column in the join's `on` statement.
* @where Sets if the value of `second` should be interpreted as a column or a value. Passing this as an argument is discouraged. Use the dedicated `joinWhere` or a join closure where possible.
*
* @return qb.models.Query.QueryBuilder
*/
public QueryBuilder function rightOuterJoin(
required any table,
any first,
string operator,
string second,
boolean where
) {
arguments.type = "right outer";
return join( argumentCollection = arguments );
}

/**
* Adds a CROSS JOIN to another table.
*
Expand Down
24 changes: 24 additions & 0 deletions tests/resources/AbstractQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -922,6 +922,24 @@ component extends="testbox.system.BaseSpec" {
}, leftJoin() );
} );

it( "can left outer join", function() {
testCase( function( builder ) {
builder.from( "users" ).leftOuterJoin( "orders", "users.id", "orders.user_id" );
}, leftOuterJoin() );
} );

it( "can full join", function() {
testCase( function( builder ) {
builder.from( "users" ).fullJoin( "orders", "users.id", "orders.user_id" );
}, fullJoin() );
} );

it( "can full outer join", function() {
testCase( function( builder ) {
builder.from( "users" ).fullOuterJoin( "orders", "users.id", "orders.user_id" );
}, fullOuterJoin() );
} );

it( "can left join on table as expression", function() {
testCase( function( builder ) {
builder
Expand Down Expand Up @@ -986,6 +1004,12 @@ component extends="testbox.system.BaseSpec" {
}, rightJoin() );
} );

it( "can right outer join", function() {
testCase( function( builder ) {
builder.from( "orders" ).rightOuterJoin( "users", "orders.user_id", "users.id" );
}, rightOuterJoin() );
} );

it( "can right join on table as expression", function() {
testCase( function( builder ) {
builder
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/MySQLQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -323,10 +323,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return { sql: "SELECT * FROM `users` INNER JOIN `contacts` ON `contacts`.`balance` < ?", bindings: [ 100 ] };
}

function fullJoin() {
return "SELECT * FROM `users` FULL JOIN `orders` ON `users`.`id` = `orders`.`user_id`";
}

function fullOuterJoin() {
return "SELECT * FROM `users` FULL OUTER JOIN `orders` ON `users`.`id` = `orders`.`user_id`";
}

function leftJoin() {
return "SELECT * FROM `users` LEFT JOIN `orders` ON `users`.`id` = `orders`.`user_id`";
}

function leftOuterJoin() {
return "SELECT * FROM `users` LEFT OUTER JOIN `orders` ON `users`.`id` = `orders`.`user_id`";
}

function leftJoinTruncatingText() {
return "SELECT * FROM `test` LEFT JOIN `last_team_tasks_queue_record` ON `last_team_tasks_queue_record`.`task_territory_id` = `team_tasks_queue`.`task_territory_id` AND (`last_team_tasks_queue_record`.`when_created` IS NULL OR `last_team_tasks_queue_record`.`when_created` <= `team_tasks_queue`.`when_created`)";
}
Expand All @@ -343,6 +355,10 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return "SELECT * FROM `orders` RIGHT JOIN `users` ON `orders`.`user_id` = `users`.`id`";
}

function rightOuterJoin() {
return "SELECT * FROM `orders` RIGHT OUTER JOIN `users` ON `orders`.`user_id` = `users`.`id`";
}

function rightJoinRaw() {
return "SELECT * FROM `users` RIGHT JOIN contacts (nolock) ON `users`.`id` = `contacts`.`id`";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/OracleQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -338,10 +338,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function fullJoin() {
return "SELECT * FROM ""USERS"" FULL JOIN ""ORDERS"" ON ""USERS"".""ID"" = ""ORDERS"".""USER_ID""";
}

function fullOuterJoin() {
return "SELECT * FROM ""USERS"" FULL OUTER JOIN ""ORDERS"" ON ""USERS"".""ID"" = ""ORDERS"".""USER_ID""";
}

function leftJoin() {
return "SELECT * FROM ""USERS"" LEFT JOIN ""ORDERS"" ON ""USERS"".""ID"" = ""ORDERS"".""USER_ID""";
}

function leftOuterJoin() {
return "SELECT * FROM ""USERS"" LEFT OUTER JOIN ""ORDERS"" ON ""USERS"".""ID"" = ""ORDERS"".""USER_ID""";
}

function leftJoinTruncatingText() {
return "SELECT * FROM ""TEST"" LEFT JOIN ""LAST_TEAM_TASKS_QUEUE_RECORD"" ON ""LAST_TEAM_TASKS_QUEUE_RECORD"".""TASK_TERRITORY_ID"" = ""TEAM_TASKS_QUEUE"".""TASK_TERRITORY_ID"" AND (""LAST_TEAM_TASKS_QUEUE_RECORD"".""WHEN_CREATED"" IS NULL OR ""LAST_TEAM_TASKS_QUEUE_RECORD"".""WHEN_CREATED"" <= ""TEAM_TASKS_QUEUE"".""WHEN_CREATED"")";
}
Expand All @@ -358,6 +370,10 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return "SELECT * FROM ""ORDERS"" RIGHT JOIN ""USERS"" ON ""ORDERS"".""USER_ID"" = ""USERS"".""ID""";
}

function rightOuterJoin() {
return "SELECT * FROM ""ORDERS"" RIGHT OUTER JOIN ""USERS"" ON ""ORDERS"".""USER_ID"" = ""USERS"".""ID""";
}

function rightJoinRaw() {
return "SELECT * FROM ""USERS"" RIGHT JOIN contacts (nolock) ON ""USERS"".""ID"" = ""CONTACTS"".""ID""";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/PostgresQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -332,10 +332,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function fullJoin() {
return "SELECT * FROM ""users"" FULL JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function fullOuterJoin() {
return "SELECT * FROM ""users"" FULL OUTER JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftJoin() {
return "SELECT * FROM ""users"" LEFT JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftOuterJoin() {
return "SELECT * FROM ""users"" LEFT OUTER JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftJoinTruncatingText() {
return "SELECT * FROM ""test"" LEFT JOIN ""last_team_tasks_queue_record"" ON ""last_team_tasks_queue_record"".""task_territory_id"" = ""team_tasks_queue"".""task_territory_id"" AND (""last_team_tasks_queue_record"".""when_created"" IS NULL OR ""last_team_tasks_queue_record"".""when_created"" <= ""team_tasks_queue"".""when_created"")";
}
Expand All @@ -352,6 +364,10 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return "SELECT * FROM ""orders"" RIGHT JOIN ""users"" ON ""orders"".""user_id"" = ""users"".""id""";
}

function rightOuterJoin() {
return "SELECT * FROM ""orders"" RIGHT OUTER JOIN ""users"" ON ""orders"".""user_id"" = ""users"".""id""";
}

function rightJoinRaw() {
return "SELECT * FROM ""users"" RIGHT JOIN contacts (nolock) ON ""users"".""id"" = ""contacts"".""id""";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/SQLiteQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -389,10 +389,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
};
}

function fullJoin() {
return "SELECT * FROM ""users"" FULL JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function fullOuterJoin() {
return "SELECT * FROM ""users"" FULL OUTER JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftJoin() {
return "SELECT * FROM ""users"" LEFT JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftOuterJoin() {
return "SELECT * FROM ""users"" LEFT OUTER JOIN ""orders"" ON ""users"".""id"" = ""orders"".""user_id""";
}

function leftJoinTruncatingText() {
return "SELECT * FROM ""test"" LEFT JOIN ""last_team_tasks_queue_record"" ON ""last_team_tasks_queue_record"".""task_territory_id"" = ""team_tasks_queue"".""task_territory_id"" AND (""last_team_tasks_queue_record"".""when_created"" IS NULL OR ""last_team_tasks_queue_record"".""when_created"" <= ""team_tasks_queue"".""when_created"")";
}
Expand All @@ -417,6 +429,10 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return "SELECT * FROM ""orders"" RIGHT JOIN ""users"" ON ""orders"".""user_id"" = ""users"".""id""";
}

function rightOuterJoin() {
return "SELECT * FROM ""orders"" RIGHT OUTER JOIN ""users"" ON ""orders"".""user_id"" = ""users"".""id""";
}

function rightJoinRaw() {
return "SELECT * FROM ""users"" RIGHT JOIN contacts (nolock) ON ""users"".""id"" = ""contacts"".""id""";
}
Expand Down
16 changes: 16 additions & 0 deletions tests/specs/Query/SqlServerQueryBuilderSpec.cfc
Original file line number Diff line number Diff line change
Expand Up @@ -323,10 +323,22 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return { sql: "SELECT * FROM [users] INNER JOIN [contacts] ON [contacts].[balance] < ?", bindings: [ 100 ] };
}

function fullJoin() {
return "SELECT * FROM [users] FULL JOIN [orders] ON [users].[id] = [orders].[user_id]";
}

function fullOuterJoin() {
return "SELECT * FROM [users] FULL OUTER JOIN [orders] ON [users].[id] = [orders].[user_id]";
}

function leftJoin() {
return "SELECT * FROM [users] LEFT JOIN [orders] ON [users].[id] = [orders].[user_id]";
}

function leftOuterJoin() {
return "SELECT * FROM [users] LEFT OUTER JOIN [orders] ON [users].[id] = [orders].[user_id]";
}

function leftJoinTruncatingText() {
return "SELECT * FROM [test] LEFT JOIN [last_team_tasks_queue_record] ON [last_team_tasks_queue_record].[task_territory_id] = [team_tasks_queue].[task_territory_id] AND ([last_team_tasks_queue_record].[when_created] IS NULL OR [last_team_tasks_queue_record].[when_created] <= [team_tasks_queue].[when_created])";
}
Expand All @@ -343,6 +355,10 @@ component extends="tests.resources.AbstractQueryBuilderSpec" {
return "SELECT * FROM [orders] RIGHT JOIN [users] ON [orders].[user_id] = [users].[id]";
}

function rightOuterJoin() {
return "SELECT * FROM [orders] RIGHT OUTER JOIN [users] ON [orders].[user_id] = [users].[id]";
}

function rightJoinRaw() {
return "SELECT * FROM [users] RIGHT JOIN contacts (nolock) ON [users].[id] = [contacts].[id]";
}
Expand Down

0 comments on commit 98e36a5

Please sign in to comment.