diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index ebb833707b11..6e31dbb0d263 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -586,6 +586,39 @@ public function joinSub($query, $as, $first, $operator = null, $second = null, $ return $this->join(new Expression($expression), $first, $operator, $second, $type, $where); } + /** + * Add a lateral join clause to the query. + * + * @param \Closure|\Illuminate\Database\Query\Builder|\Illuminate\Database\Eloquent\Builder|string $query + * @param string $as + * @param string $type + * @return $this + */ + public function joinLateral($query, string $as, string $type = 'inner') + { + [$query, $bindings] = $this->createSub($query); + + $expression = '('.$query.') as '.$this->grammar->wrapTable($as); + + $this->addBinding($bindings, 'join'); + + $this->joins[] = $this->newJoinLateralClause($this, $type, new Expression($expression)); + + return $this; + } + + /** + * Add a lateral left join to the query. + * + * @param \Closure|\Illuminate\Database\Query\Builder|\Illuminate\Database\Eloquent\Builder|string $query + * @param string $as + * @return $this + */ + public function leftJoinLateral($query, string $as) + { + return $this->joinLateral($query, $as, 'left'); + } + /** * Add a left join to the query. * @@ -725,6 +758,19 @@ protected function newJoinClause(self $parentQuery, $type, $table) return new JoinClause($parentQuery, $type, $table); } + /** + * Get a new join lateral clause. + * + * @param \Illuminate\Database\Query\Builder $parentQuery + * @param string $type + * @param string $table + * @return \Illuminate\Database\Query\JoinLateralClause + */ + protected function newJoinLateralClause(self $parentQuery, $type, $table) + { + return new JoinLateralClause($parentQuery, $type, $table); + } + /** * Merge an array of where clauses and bindings. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index a03cdcb03346..b8eed21e69fd 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -7,6 +7,7 @@ use Illuminate\Database\Grammar as BaseGrammar; use Illuminate\Database\Query\Builder; use Illuminate\Database\Query\JoinClause; +use Illuminate\Database\Query\JoinLateralClause; use Illuminate\Support\Arr; use RuntimeException; @@ -182,10 +183,28 @@ protected function compileJoins(Builder $query, $joins) $tableAndNestedJoins = is_null($join->joins) ? $table : '('.$table.$nestedJoins.')'; + if ($join instanceof JoinLateralClause) { + return $this->compileJoinLateral($join, $tableAndNestedJoins); + } + return trim("{$join->type} join {$tableAndNestedJoins} {$this->compileWheres($join)}"); })->implode(' '); } + /** + * Compile a "lateral join" clause. + * + * @param \Illuminate\Database\Query\JoinLateralClause $join + * @param string $expression + * @return string + * + * @throws \RuntimeException + */ + public function compileJoinLateral(JoinLateralClause $join, string $expression): string + { + throw new RuntimeException('This database engine does not support lateral joins.'); + } + /** * Compile the "where" portions of the query. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 1365d8efe620..3d900eeb3c24 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -3,6 +3,7 @@ namespace Illuminate\Database\Query\Grammars; use Illuminate\Database\Query\Builder; +use Illuminate\Database\Query\JoinLateralClause; use Illuminate\Support\Str; class MySqlGrammar extends Grammar @@ -267,6 +268,18 @@ public function compileUpsert(Builder $query, array $values, array $uniqueBy, ar return $sql.$columns; } + /** + * Compile a "lateral join" clause. + * + * @param \Illuminate\Database\Query\JoinLateralClause $join + * @param string $expression + * @return string + */ + public function compileJoinLateral(JoinLateralClause $join, string $expression): string + { + return trim("{$join->type} join lateral {$expression} on true"); + } + /** * Prepare a JSON column being updated using the JSON_SET function. * diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index b39a20a0a5d0..c22720a05c7c 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -3,6 +3,7 @@ namespace Illuminate\Database\Query\Grammars; use Illuminate\Database\Query\Builder; +use Illuminate\Database\Query\JoinLateralClause; use Illuminate\Support\Arr; use Illuminate\Support\Str; @@ -409,6 +410,18 @@ public function compileUpsert(Builder $query, array $values, array $uniqueBy, ar return $sql.$columns; } + /** + * Compile a "lateral join" clause. + * + * @param \Illuminate\Database\Query\JoinLateralClause $join + * @param string $expression + * @return string + */ + public function compileJoinLateral(JoinLateralClause $join, string $expression): string + { + return trim("{$join->type} join lateral {$expression} on true"); + } + /** * Prepares a JSON column being updated using the JSONB_SET function. * diff --git a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php index f68722a64bce..062041c37d30 100755 --- a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php @@ -3,6 +3,7 @@ namespace Illuminate\Database\Query\Grammars; use Illuminate\Database\Query\Builder; +use Illuminate\Database\Query\JoinLateralClause; use Illuminate\Support\Arr; use Illuminate\Support\Str; @@ -444,6 +445,20 @@ public function prepareBindingsForUpdate(array $bindings, array $values) ); } + /** + * Compile a "lateral join" clause. + * + * @param \Illuminate\Database\Query\JoinLateralClause $join + * @param string $expression + * @return string + */ + public function compileJoinLateral(JoinLateralClause $join, string $expression): string + { + $type = $join->type == 'left' ? 'outer' : 'cross'; + + return trim("{$type} apply {$expression}"); + } + /** * Compile the SQL statement to define a savepoint. * diff --git a/src/Illuminate/Database/Query/JoinLateralClause.php b/src/Illuminate/Database/Query/JoinLateralClause.php new file mode 100644 index 000000000000..1be31d29626a --- /dev/null +++ b/src/Illuminate/Database/Query/JoinLateralClause.php @@ -0,0 +1,8 @@ +from('users')->rightJoinSub(['foo'], 'sub', 'users.id', '=', 'sub.id'); } + public function testJoinLateral() + { + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral('select * from `contacts` where `contracts`.`user_id` = `users`.`id`', 'sub'); + $this->assertSame('select * from `users` inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id`) as `sub` on true', $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral(function ($q) { + $q->from('contacts')->whereColumn('contracts.user_id', 'users.id'); + }, 'sub'); + $this->assertSame('select * from `users` inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id`) as `sub` on true', $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $sub = $this->getMySqlBuilder(); + $sub->getConnection()->shouldReceive('getDatabaseName'); + $eloquentBuilder = new EloquentBuilder($sub->from('contacts')->whereColumn('contracts.user_id', 'users.id')); + $builder->from('users')->joinLateral($eloquentBuilder, 'sub'); + $this->assertSame('select * from `users` inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id`) as `sub` on true', $builder->toSql()); + + $sub1 = $this->getMySqlBuilder(); + $sub1->getConnection()->shouldReceive('getDatabaseName'); + $sub1 = $sub1->from('contacts')->whereColumn('contracts.user_id', 'users.id')->where('name', 'foo'); + + $sub2 = $this->getMySqlBuilder(); + $sub2->getConnection()->shouldReceive('getDatabaseName'); + $sub2 = $sub2->from('contacts')->whereColumn('contracts.user_id', 'users.id')->where('name', 'bar'); + + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral($sub1, 'sub1')->joinLateral($sub2, 'sub2'); + + $expected = 'select * from `users` '; + $expected .= 'inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id` and `name` = ?) as `sub1` on true '; + $expected .= 'inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id` and `name` = ?) as `sub2` on true'; + + $this->assertEquals($expected, $builder->toSql()); + $this->assertEquals(['foo', 'bar'], $builder->getRawBindings()['join']); + + $this->expectException(InvalidArgumentException::class); + $builder = $this->getMySqlBuilder(); + $builder->from('users')->joinLateral(['foo'], 'sub'); + } + + public function testJoinLateralSQLite() + { + $this->expectException(RuntimeException::class); + $builder = $this->getSQLiteBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral(function ($q) { + $q->from('contacts')->whereColumn('contracts.user_id', 'users.id'); + }, 'sub')->toSql(); + } + + public function testJoinLateralPostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral(function ($q) { + $q->from('contacts')->whereColumn('contracts.user_id', 'users.id'); + }, 'sub'); + $this->assertSame('select * from "users" inner join lateral (select * from "contacts" where "contracts"."user_id" = "users"."id") as "sub" on true', $builder->toSql()); + } + + public function testJoinLateralSqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->joinLateral(function ($q) { + $q->from('contacts')->whereColumn('contracts.user_id', 'users.id'); + }, 'sub'); + $this->assertSame('select * from [users] cross apply (select * from [contacts] where [contracts].[user_id] = [users].[id]) as [sub]', $builder->toSql()); + } + + public function testJoinLateralWithPrefix() + { + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->getGrammar()->setTablePrefix('prefix_'); + $builder->from('users')->joinLateral('select * from `contacts` where `contracts`.`user_id` = `users`.`id`', 'sub'); + $this->assertSame('select * from `prefix_users` inner join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id`) as `prefix_sub` on true', $builder->toSql()); + } + + public function testLeftJoinLateral() + { + $builder = $this->getMySqlBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + + $sub = $this->getMySqlBuilder(); + $sub->getConnection()->shouldReceive('getDatabaseName'); + + $builder->from('users')->leftJoinLateral($sub->from('contacts')->whereColumn('contracts.user_id', 'users.id'), 'sub'); + $this->assertSame('select * from `users` left join lateral (select * from `contacts` where `contracts`.`user_id` = `users`.`id`) as `sub` on true', $builder->toSql()); + + $this->expectException(InvalidArgumentException::class); + $builder = $this->getBuilder(); + $builder->from('users')->leftJoinLateral(['foo'], 'sub'); + } + + public function testLeftJoinLateralSqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->getConnection()->shouldReceive('getDatabaseName'); + $builder->from('users')->leftJoinLateral(function ($q) { + $q->from('contacts')->whereColumn('contracts.user_id', 'users.id'); + }, 'sub'); + $this->assertSame('select * from [users] outer apply (select * from [contacts] where [contracts].[user_id] = [users].[id]) as [sub]', $builder->toSql()); + } + public function testRawExpressionsInSelect() { $builder = $this->getBuilder(); diff --git a/tests/Integration/Database/MySql/JoinLateralTest.php b/tests/Integration/Database/MySql/JoinLateralTest.php new file mode 100644 index 000000000000..969308ff856c --- /dev/null +++ b/tests/Integration/Database/MySql/JoinLateralTest.php @@ -0,0 +1,117 @@ +id('id'); + $table->string('name'); + }); + + Schema::create('posts', function (Blueprint $table) { + $table->id('id'); + $table->string('title'); + $table->integer('rating'); + $table->unsignedBigInteger('user_id'); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('posts'); + Schema::drop('users'); + } + + protected function setUp(): void + { + parent::setUp(); + + $this->checkMySqlVersion(); + + DB::table('users')->insert([ + ['name' => Str::random()], + ['name' => Str::random()], + ]); + + DB::table('posts')->insert([ + ['title' => Str::random(), 'rating' => 1, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 3, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 7, 'user_id' => 1], + ]); + } + + protected function checkMySqlVersion() + { + $mySqlVersion = DB::select('select version()')[0]->{'version()'} ?? ''; + + if (strpos($mySqlVersion, 'Maria') !== false) { + $this->markTestSkipped('Lateral joins are not supported on MariaDB'.__CLASS__); + } elseif ((float) $mySqlVersion < '8.0.14') { + $this->markTestSkipped('Lateral joins are not supported on MySQL < 8.0.14'.__CLASS__); + } + } + + public function testJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(0, $userWithoutPosts); + } + + public function testLeftJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(1, $userWithoutPosts); + $this->assertNull($userWithoutPosts[0]->best_post_title); + $this->assertNull($userWithoutPosts[0]->best_post_rating); + } +} diff --git a/tests/Integration/Database/Postgres/JoinLateralTest.php b/tests/Integration/Database/Postgres/JoinLateralTest.php new file mode 100644 index 000000000000..e17f5622efdd --- /dev/null +++ b/tests/Integration/Database/Postgres/JoinLateralTest.php @@ -0,0 +1,104 @@ +id('id'); + $table->string('name'); + }); + + Schema::create('posts', function (Blueprint $table) { + $table->id('id'); + $table->string('title'); + $table->integer('rating'); + $table->unsignedBigInteger('user_id'); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('posts'); + Schema::drop('users'); + } + + protected function setUp(): void + { + parent::setUp(); + + DB::table('users')->insert([ + ['name' => Str::random()], + ['name' => Str::random()], + ]); + + DB::table('posts')->insert([ + ['title' => Str::random(), 'rating' => 1, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 3, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 7, 'user_id' => 1], + ]); + } + + public function testJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(0, $userWithoutPosts); + } + + public function testLeftJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(1, $userWithoutPosts); + $this->assertNull($userWithoutPosts[0]->best_post_title); + $this->assertNull($userWithoutPosts[0]->best_post_rating); + } +} diff --git a/tests/Integration/Database/SqlServer/JoinLateralTest.php b/tests/Integration/Database/SqlServer/JoinLateralTest.php new file mode 100644 index 000000000000..df11c5517585 --- /dev/null +++ b/tests/Integration/Database/SqlServer/JoinLateralTest.php @@ -0,0 +1,100 @@ +id('id'); + $table->string('name'); + }); + + Schema::create('posts', function (Blueprint $table) { + $table->id('id'); + $table->string('title'); + $table->integer('rating'); + $table->unsignedBigInteger('user_id'); + }); + } + + protected function destroyDatabaseMigrations() + { + Schema::drop('posts'); + Schema::drop('users'); + } + + protected function setUp(): void + { + parent::setUp(); + + DB::table('users')->insert([ + ['name' => Str::random()], + ['name' => Str::random()], + ]); + + DB::table('posts')->insert([ + ['title' => Str::random(), 'rating' => 1, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 3, 'user_id' => 1], + ['title' => Str::random(), 'rating' => 7, 'user_id' => 1], + ]); + } + + public function testJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, (int) $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, (int) $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->joinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(0, $userWithoutPosts); + } + + public function testLeftJoinLateral() + { + $subquery = DB::table('posts') + ->select('title as best_post_title', 'rating as best_post_rating') + ->whereColumn('user_id', 'users.id') + ->orderBy('rating', 'desc') + ->limit(2); + + $userWithPosts = DB::table('users') + ->where('id', 1) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(2, $userWithPosts); + $this->assertEquals(7, (int) $userWithPosts[0]->best_post_rating); + $this->assertEquals(3, (int) $userWithPosts[1]->best_post_rating); + + $userWithoutPosts = DB::table('users') + ->where('id', 2) + ->leftJoinLateral($subquery, 'best_post') + ->get(); + + $this->assertCount(1, $userWithoutPosts); + $this->assertNull($userWithoutPosts[0]->best_post_title); + $this->assertNull($userWithoutPosts[0]->best_post_rating); + } +}