From 47881dadfa604118d1ddbd97f9d53b0801d0c7bb Mon Sep 17 00:00:00 2001 From: Guy Sartorelli Date: Fri, 4 Aug 2023 15:38:28 +1200 Subject: [PATCH] NEW Add abstraction for sql RIGHT JOIN --- src/ORM/DataQuery.php | 20 +++++++ src/ORM/Queries/SQLConditionalExpression.php | 40 +++++++++----- tests/php/ORM/DataQueryTest.php | 33 ++++++++---- tests/php/ORM/SQLSelectTest.php | 57 ++++++++++---------- 4 files changed, 98 insertions(+), 52 deletions(-) diff --git a/src/ORM/DataQuery.php b/src/ORM/DataQuery.php index b37f1669938..4ec928a71a1 100644 --- a/src/ORM/DataQuery.php +++ b/src/ORM/DataQuery.php @@ -831,6 +831,26 @@ public function leftJoin($table, $onClause, $alias = null, $order = 20, $paramet return $this; } + /** + * Add a RIGHT JOIN clause to this query. + * + * @param string $table The unquoted table to join to. + * @param string $onClause The filter for the join (escaped SQL statement). + * @param string $alias An optional alias name (unquoted) + * @param int $order A numerical index to control the order that joins are added to the query; lower order values + * will cause the query to appear first. The default is 20, and joins created automatically by the + * ORM have a value of 10. + * @param array $parameters Any additional parameters if the join is a parameterised subquery + * @return $this + */ + public function rightJoin($table, $onClause, $alias = null, $order = 20, $parameters = []) + { + if ($table) { + $this->query->addRightJoin($table, $onClause, $alias, $order, $parameters); + } + return $this; + } + /** * Prefix of all joined table aliases. E.g. ->filter('Banner.Image.Title)' * Will join the Banner, and then Image relations diff --git a/src/ORM/Queries/SQLConditionalExpression.php b/src/ORM/Queries/SQLConditionalExpression.php index 55d6ae5c297..b5cf12f1c11 100644 --- a/src/ORM/Queries/SQLConditionalExpression.php +++ b/src/ORM/Queries/SQLConditionalExpression.php @@ -136,17 +136,25 @@ public function useConjunction() */ public function addLeftJoin($table, $onPredicate, $tableAlias = '', $order = 20, $parameters = []) { - if (!$tableAlias) { - $tableAlias = $table; - } - $this->from[$tableAlias] = [ - 'type' => 'LEFT', - 'table' => $table, - 'filter' => [$onPredicate], - 'order' => $order, - 'parameters' => $parameters - ]; - return $this; + return $this->addJoin($table, 'LEFT', $onPredicate, $tableAlias, $order, $parameters); + } + + /** + * Add a RIGHT JOIN criteria to the tables list. + * + * @param string $table Unquoted table name + * @param string $onPredicate The "ON" SQL fragment in a "RIGHT JOIN ... AS ... ON ..." statement, Needs to be valid + * (quoted) SQL. + * @param string $tableAlias Optional alias which makes it easier to identify and replace joins later on + * @param int $order A numerical index to control the order that joins are added to the query; lower order values + * will cause the query to appear first. The default is 20, and joins created automatically by the + * ORM have a value of 10. + * @param array $parameters Any additional parameters if the join is a parameterized subquery + * @return $this Self reference + */ + public function addRightJoin($table, $onPredicate, $tableAlias = '', $order = 20, $parameters = []) + { + return $this->addJoin($table, 'RIGHT', $onPredicate, $tableAlias, $order, $parameters); } /** @@ -163,12 +171,20 @@ public function addLeftJoin($table, $onPredicate, $tableAlias = '', $order = 20, * @return $this Self reference */ public function addInnerJoin($table, $onPredicate, $tableAlias = null, $order = 20, $parameters = []) + { + return $this->addJoin($table, 'INNER', $onPredicate, $tableAlias, $order, $parameters); + } + + /** + * Add a JOIN criteria + */ + private function addJoin($table, $type, $onPredicate, $tableAlias = null, $order = 20, $parameters = []): static { if (!$tableAlias) { $tableAlias = $table; } $this->from[$tableAlias] = [ - 'type' => 'INNER', + 'type' => $type, 'table' => $table, 'filter' => [$onPredicate], 'order' => $order, diff --git a/tests/php/ORM/DataQueryTest.php b/tests/php/ORM/DataQueryTest.php index 34ae7619d6b..167a7ac6383 100644 --- a/tests/php/ORM/DataQueryTest.php +++ b/tests/php/ORM/DataQueryTest.php @@ -51,22 +51,33 @@ public function testSortByJoinedFieldRetainsSourceInformation() $this->assertEquals('Foo', $result['Title']); } + public function provideJoins() + { + return [ + [ + 'joinMethod' => 'innerJoin', + 'joinType' => 'INNER', + ], + [ + 'joinMethod' => 'leftJoin', + 'joinType' => 'LEFT', + ], + [ + 'joinMethod' => 'rightJoin', + 'joinType' => 'RIGHT', + ], + ]; + } + /** - * Test the leftJoin() and innerJoin method of the DataQuery object + * @dataProvider provideJoins */ - public function testJoins() + public function testJoins($joinMethod, $joinType) { $dq = new DataQuery(Member::class); - $dq->innerJoin("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\""); - $this->assertSQLContains( - "INNER JOIN \"Group_Members\" ON \"Group_Members\".\"MemberID\" = \"Member\".\"ID\"", - $dq->sql($parameters) - ); - - $dq = new DataQuery(Member::class); - $dq->leftJoin("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\""); + $dq->$joinMethod("Group_Members", "\"Group_Members\".\"MemberID\" = \"Member\".\"ID\""); $this->assertSQLContains( - "LEFT JOIN \"Group_Members\" ON \"Group_Members\".\"MemberID\" = \"Member\".\"ID\"", + "$joinType JOIN \"Group_Members\" ON \"Group_Members\".\"MemberID\" = \"Member\".\"ID\"", $dq->sql($parameters) ); } diff --git a/tests/php/ORM/SQLSelectTest.php b/tests/php/ORM/SQLSelectTest.php index be70ccb3a93..f26293ebe9a 100755 --- a/tests/php/ORM/SQLSelectTest.php +++ b/tests/php/ORM/SQLSelectTest.php @@ -435,16 +435,18 @@ public function testFiltersOnFK() ); } - public function testInnerJoin() + public function testJoinSQL() { $query = new SQLSelect(); $query->setFrom('MyTable'); $query->addInnerJoin('MyOtherTable', 'MyOtherTable.ID = 2'); + $query->addRightJoin('MySecondTable', 'MyOtherTable.ID = MySecondTable.ID'); $query->addLeftJoin('MyLastTable', 'MyOtherTable.ID = MyLastTable.ID'); $this->assertSQLEquals( 'SELECT * FROM MyTable ' . 'INNER JOIN "MyOtherTable" ON MyOtherTable.ID = 2 ' . + 'RIGHT JOIN "MySecondTable" ON MyOtherTable.ID = MySecondTable.ID ' . 'LEFT JOIN "MyLastTable" ON MyOtherTable.ID = MyLastTable.ID', $query->sql($parameters) ); @@ -452,12 +454,14 @@ public function testInnerJoin() $query = new SQLSelect(); $query->setFrom('MyTable'); $query->addInnerJoin('MyOtherTable', 'MyOtherTable.ID = 2', 'table1'); - $query->addLeftJoin('MyLastTable', 'MyOtherTable.ID = MyLastTable.ID', 'table2'); + $query->addRightJoin('MySecondTable', 'MyOtherTable.ID = MySecondTable.ID', 'table2'); + $query->addLeftJoin('MyLastTable', 'MyOtherTable.ID = MyLastTable.ID', 'table3'); $this->assertSQLEquals( 'SELECT * FROM MyTable ' . 'INNER JOIN "MyOtherTable" AS "table1" ON MyOtherTable.ID = 2 ' . - 'LEFT JOIN "MyLastTable" AS "table2" ON MyOtherTable.ID = MyLastTable.ID', + 'RIGHT JOIN "MySecondTable" AS "table2" ON MyOtherTable.ID = MySecondTable.ID ' . + 'LEFT JOIN "MyLastTable" AS "table3" ON MyOtherTable.ID = MyLastTable.ID', $query->sql($parameters) ); } @@ -739,38 +743,33 @@ public function testLimitSetFromClauseString() $this->assertEquals(10, $limit['start']); } - public function testParameterisedInnerJoins() + public function provideParameterisedJoinSQL() { - $query = new SQLSelect(); - $query->setSelect(['"SQLSelectTest_DO"."Name"', '"SubSelect"."Count"']); - $query->setFrom('"SQLSelectTest_DO"'); - $query->addInnerJoin( - '(SELECT "Title", COUNT(*) AS "Count" FROM "SQLSelectTestBase" GROUP BY "Title" HAVING "Title" NOT LIKE ?)', - '"SQLSelectTest_DO"."Name" = "SubSelect"."Title"', - 'SubSelect', - 20, - ['%MyName%'] - ); - $query->addWhere(['"SQLSelectTest_DO"."Date" > ?' => '2012-08-08 12:00']); - - $this->assertSQLEquals( - 'SELECT "SQLSelectTest_DO"."Name", "SubSelect"."Count" - FROM "SQLSelectTest_DO" INNER JOIN (SELECT "Title", COUNT(*) AS "Count" FROM "SQLSelectTestBase" - GROUP BY "Title" HAVING "Title" NOT LIKE ?) AS "SubSelect" ON "SQLSelectTest_DO"."Name" = - "SubSelect"."Title" - WHERE ("SQLSelectTest_DO"."Date" > ?)', - $query->sql($parameters) - ); - $this->assertEquals(['%MyName%', '2012-08-08 12:00'], $parameters); - $query->execute(); + return [ + [ + 'joinMethod' => 'addInnerJoin', + 'joinType' => 'INNER', + ], + [ + 'joinMethod' => 'addLeftJoin', + 'joinType' => 'LEFT', + ], + [ + 'joinMethod' => 'addRightJoin', + 'joinType' => 'RIGHT', + ], + ]; } - public function testParameterisedLeftJoins() + /** + * @dataProvider provideParameterisedJoinSQL + */ + public function testParameterisedJoinSQL($joinMethod, $joinType) { $query = new SQLSelect(); $query->setSelect(['"SQLSelectTest_DO"."Name"', '"SubSelect"."Count"']); $query->setFrom('"SQLSelectTest_DO"'); - $query->addLeftJoin( + $query->$joinMethod( '(SELECT "Title", COUNT(*) AS "Count" FROM "SQLSelectTestBase" GROUP BY "Title" HAVING "Title" NOT LIKE ?)', '"SQLSelectTest_DO"."Name" = "SubSelect"."Title"', 'SubSelect', @@ -781,7 +780,7 @@ public function testParameterisedLeftJoins() $this->assertSQLEquals( 'SELECT "SQLSelectTest_DO"."Name", "SubSelect"."Count" - FROM "SQLSelectTest_DO" LEFT JOIN (SELECT "Title", COUNT(*) AS "Count" FROM "SQLSelectTestBase" + FROM "SQLSelectTest_DO" ' . $joinType . ' JOIN (SELECT "Title", COUNT(*) AS "Count" FROM "SQLSelectTestBase" GROUP BY "Title" HAVING "Title" NOT LIKE ?) AS "SubSelect" ON "SQLSelectTest_DO"."Name" = "SubSelect"."Title" WHERE ("SQLSelectTest_DO"."Date" > ?)',