Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[10.x] Add Lateral Join to Query Builder #50050

Merged
merged 2 commits into from
Feb 25, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
46 changes: 46 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down Expand Up @@ -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.
*
Expand Down
19 changes: 19 additions & 0 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;

Expand Down Expand Up @@ -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.
*
Expand Down
13 changes: 13 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -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.
*
Expand Down
13 changes: 13 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;

Expand Down Expand Up @@ -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.
*
Expand Down
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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;

Expand Down Expand Up @@ -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.
*
Expand Down
8 changes: 8 additions & 0 deletions src/Illuminate/Database/Query/JoinLateralClause.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
<?php

namespace Illuminate\Database\Query;

class JoinLateralClause extends JoinClause
{
Bakke marked this conversation as resolved.
Show resolved Hide resolved
//
}
111 changes: 111 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -2526,6 +2526,117 @@ public function testRightJoinSub()
$builder->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();
Expand Down
Loading
Loading