Skip to content

Commit

Permalink
Add Query Builder test for lateral join methods
Browse files Browse the repository at this point in the history
  • Loading branch information
Bakke committed Feb 15, 2024
1 parent 6ef9110 commit 0d0539f
Show file tree
Hide file tree
Showing 5 changed files with 126 additions and 33 deletions.
12 changes: 6 additions & 6 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -176,30 +176,30 @@ protected function compileFrom(Builder $query, $table)
protected function compileJoins(Builder $query, $joins)
{
return collect($joins)->map(function ($join) use ($query) {
if ($join->lateral) {
return $this->joinLateral($query, $join);
}

$table = $this->wrapTable($join->table);

$nestedJoins = is_null($join->joins) ? '' : ' '.$this->compileJoins($query, $join->joins);

$tableAndNestedJoins = is_null($join->joins) ? $table : '('.$table.$nestedJoins.')';

if ($join->lateral) {
return $this->joinLateral($join, $tableAndNestedJoins);
}

return trim("{$join->type} join {$tableAndNestedJoins} {$this->compileWheres($join)}");
})->implode(' ');
}

/**
* Compile a "lateral join" clause.
*
* @param \Illuminate\Database\Query\Builder $query
* @param \Illuminate\Database\Query\JoinClause $join
* @param string $expression
* @return string
*
* @throws \RuntimeException
*/
public function joinLateral(Builder $query, JoinClause $join)
public function joinLateral(JoinClause $join, string $expression)
{
throw new RuntimeException('This database engine does not support lateral joins.');
}
Expand Down
12 changes: 3 additions & 9 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -237,19 +237,13 @@ protected function compileUpdateColumns(Builder $query, array $values)
/**
* Compile a "lateral join" clause.
*
* @param \Illuminate\Database\Query\Builder $query
* @param \Illuminate\Database\Query\JoinClause $join
* @param string $expression
* @return string
*/
public function joinLateral(Builder $query, JoinClause $join)
public function joinLateral(JoinClause $join, string $expression)
{
$table = $this->wrapTable($join->table);

$nestedJoins = is_null($join->joins) ? '' : ' '.$this->compileJoins($query, $join->joins);

$tableAndNestedJoins = is_null($join->joins) ? $table : '('.$table.$nestedJoins.')';

return trim("{$join->type} join lateral {$tableAndNestedJoins} on true");
return trim("{$join->type} join lateral {$expression} on true");
}

/**
Expand Down
12 changes: 3 additions & 9 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -389,19 +389,13 @@ protected function compileUpdateColumns(Builder $query, array $values)
/**
* Compile a "lateral join" clause.
*
* @param \Illuminate\Database\Query\Builder $query
* @param \Illuminate\Database\Query\JoinClause $join
* @param string $expression
* @return string
*/
public function joinLateral(Builder $query, JoinClause $join)
public function joinLateral(JoinClause $join, string $expression)
{
$table = $this->wrapTable($join->table);

$nestedJoins = is_null($join->joins) ? '' : ' '.$this->compileJoins($query, $join->joins);

$tableAndNestedJoins = is_null($join->joins) ? $table : '('.$table.$nestedJoins.')';

return trim("{$join->type} join lateral {$tableAndNestedJoins} on true");
return trim("{$join->type} join lateral {$expression} on true");
}

/**
Expand Down
12 changes: 3 additions & 9 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -390,21 +390,15 @@ protected function compileUpdateWithJoins(Builder $query, $table, $columns, $whe
/**
* Compile a "lateral join" clause.
*
* @param \Illuminate\Database\Query\Builder $query
* @param \Illuminate\Database\Query\JoinClause $join
* @param string $expression
* @return string
*/
public function joinLateral(Builder $query, JoinClause $join)
public function joinLateral(JoinClause $join, string $expression)
{
$table = $this->wrapTable($join->table);

$nestedJoins = is_null($join->joins) ? '' : ' '.$this->compileJoins($query, $join->joins);

$tableAndNestedJoins = is_null($join->joins) ? $table : '('.$table.$nestedJoins.')';

$type = $join->type == 'left' ? 'outer' : 'cross';

return trim("{$type} apply {$tableAndNestedJoins}");
return trim("{$type} apply {$expression}");
}

/**
Expand Down
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

0 comments on commit 0d0539f

Please sign in to comment.