Support Lateral Join to Hyperf\Database\Query\Builder (#6774)

This commit is contained in:
zds 2024-05-23 11:18:13 +08:00 committed by GitHub
parent 156ec0670a
commit 6f3c32a86d
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
13 changed files with 329 additions and 41 deletions

View File

@ -5,6 +5,7 @@
- [#6757](https://github.com/hyperf/hyperf/pull/6757) Added `Hyperf\Collection\LazyCollection`.
- [#6763](https://github.com/hyperf/hyperf/pull/6763) Added `Premature end of data` into `DetectsLostConnections`.
- [#6767](https://github.com/hyperf/hyperf/pull/6767) Support `whereAll/orWhereAll` `whereAny/orWhereAny` for `Hyperf\Database\Query\Builder`.
- [#6774](https://github.com/hyperf/hyperf/pull/6774) Support Lateral Join to `Hyperf\Database\Query\Builder`
- [#6781](https://github.com/hyperf/hyperf/pull/6781) Added some methods to `Hyperf\Collection\Arr`.
## Optimized

View File

@ -15,6 +15,7 @@ namespace Hyperf\Database\PgSQL\Query\Grammars;
use Hyperf\Collection\Arr;
use Hyperf\Database\Query\Builder;
use Hyperf\Database\Query\Grammars\Grammar;
use Hyperf\Database\Query\JoinLateralClause;
use Hyperf\Stringable\Str;
use function Hyperf\Collection\collect;
@ -153,6 +154,14 @@ class PostgresGrammar extends Grammar
return ['truncate ' . $this->wrapTable($query->from) . ' restart identity cascade' => []];
}
/**
* Compile a "lateral join" clause.
*/
public function compileJoinLateral(JoinLateralClause $join, string $expression): string
{
return trim("{$join->type} join lateral {$expression} on true");
}
/**
* Substitute the given bindings into the given raw SQL query.
*

View File

@ -22,10 +22,11 @@ use Hyperf\Database\Query\Builder;
use Hyperf\Database\Schema\Blueprint;
use Hyperf\Database\Schema\Schema;
use Hyperf\DbConnection\Db;
use Hyperf\Stringable\Str;
use HyperfTest\Database\PgSQL\Stubs\ContainerStub;
use HyperfTest\Database\PgSQL\Stubs\SwooleVersionStub;
use Mockery as m;
use PHPUnit\Framework\Attributes\CoversNothing;
use PHPUnit\Framework\Attributes\RequiresPhpExtension;
use PHPUnit\Framework\TestCase;
/**
@ -42,9 +43,9 @@ class DatabasePostgresBuilderTest extends TestCase
m::close();
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testCreateDatabase()
{
SwooleVersionStub::skipV6();
$grammar = new PostgresGrammar();
$connection = m::mock(Connection::class);
@ -58,9 +59,9 @@ class DatabasePostgresBuilderTest extends TestCase
$this->assertEquals(true, $builder->createDatabase('my_temporary_database'));
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testDropDatabaseIfExists()
{
SwooleVersionStub::skipV6();
$grammar = new PostgresGrammar();
$connection = m::mock(Connection::class);
@ -73,9 +74,9 @@ class DatabasePostgresBuilderTest extends TestCase
$this->assertEquals(true, $builder->dropDatabaseIfExists('my_database_a'));
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testWhereFullText()
{
SwooleVersionStub::skipV6();
$builder = $this->getPostgresBuilderWithProcessor();
$builder->select('*')->from('users')->whereFullText('body', 'Hello World');
$this->assertSame('select * from "users" where (to_tsvector(\'english\', "body")) @@ plainto_tsquery(\'english\', ?)', $builder->toSql());
@ -112,9 +113,95 @@ class DatabasePostgresBuilderTest extends TestCase
$this->assertEquals(['Car Plane'], $builder->getBindings());
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testJoinLateralPostgres()
{
$builder = $this->getPostgresBuilderWithProcessor();
$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());
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testJoinLateralTest(): void
{
$container = ContainerStub::getContainer();
$container->shouldReceive('get')->with(Db::class)->andReturn(new Db($container));
Schema::dropIfExists('join_posts');
Schema::dropIfExists('join_users');
Schema::create('join_users', static function (Blueprint $table) {
$table->id('id');
$table->string('name');
});
Schema::create('join_posts', static function (Blueprint $table) {
$table->id('id');
$table->string('title');
$table->integer('rating');
$table->unsignedBigInteger('user_id');
});
Db::table('join_users')->insert([
['name' => Str::random()],
['name' => Str::random()],
]);
Db::table('join_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],
]);
$subquery = Db::table('join_posts')
->select('title as best_post_title', 'rating as best_post_rating')
->whereColumn('user_id', 'join_users.id')
->orderBy('rating', 'desc')
->limit(2);
$userWithPosts = Db::table('join_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('join_users')
->where('id', 2)
->joinLateral($subquery, 'best_post')
->get();
$this->assertCount(0, $userWithoutPosts);
$subquery = Db::table('join_posts')
->select('title as best_post_title', 'rating as best_post_rating')
->whereColumn('user_id', 'join_users.id')
->orderBy('rating', 'desc')
->limit(2);
$userWithPosts = Db::table('join_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('join_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']);
}
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testWhereFullTextForReal()
{
SwooleVersionStub::skipV6();
$container = ContainerStub::getContainer();
$container->shouldReceive('get')->with(Db::class)->andReturn(new Db($container));

View File

@ -23,9 +23,9 @@ use Hyperf\Database\Query\Builder;
use Hyperf\Database\Schema\Schema;
use Hyperf\Support\Filesystem\Filesystem;
use HyperfTest\Database\PgSQL\Stubs\ContainerStub;
use HyperfTest\Database\PgSQL\Stubs\SwooleVersionStub;
use Mockery;
use PHPUnit\Framework\Attributes\CoversNothing;
use PHPUnit\Framework\Attributes\RequiresPhpExtension;
use PHPUnit\Framework\TestCase;
use Symfony\Component\Console\Style\OutputStyle;
@ -34,13 +34,13 @@ use Symfony\Component\Console\Style\OutputStyle;
* @coversNothing
*/
#[CoversNothing]
#[RequiresPhpExtension('swoole', '< 6.0')]
class PostgreSqlSwooleExtConnectionTest extends TestCase
{
protected Migrator $migrator;
public function setUp(): void
{
SwooleVersionStub::skipV6();
$resolver = ContainerStub::getContainer()->get(ConnectionResolverInterface::class);
$this->migrator = new Migrator(

View File

@ -15,8 +15,8 @@ namespace HyperfTest\Database\PgSQL\DBAL;
use Hyperf\Database\PgSQL\DBAL\Connection;
use Hyperf\Database\PgSQL\DBAL\Result;
use Hyperf\Database\PgSQL\DBAL\Statement;
use HyperfTest\Database\PgSQL\Stubs\SwooleVersionStub;
use PHPUnit\Framework\Attributes\CoversNothing;
use PHPUnit\Framework\Attributes\RequiresPhpExtension;
use PHPUnit\Framework\TestCase;
use Swoole\Coroutine\PostgreSQL;
@ -25,13 +25,13 @@ use Swoole\Coroutine\PostgreSQL;
* @coversNothing
*/
#[CoversNothing]
#[RequiresPhpExtension('swoole', '< 6.0')]
class ConnectionTest extends TestCase
{
protected Connection $connection;
public function setUp(): void
{
SwooleVersionStub::skipV6();
$pgsql = new PostgreSQL();
$connected = $pgsql->connect('host=127.0.0.1 port=5432 dbname=postgres user=postgres password=postgres');
if (! $connected) {

View File

@ -1,30 +0,0 @@
<?php
declare(strict_types=1);
/**
* This file is part of Hyperf.
*
* @link https://www.hyperf.io
* @document https://hyperf.wiki
* @contact group@hyperf.io
* @license https://github.com/hyperf/hyperf/blob/master/LICENSE
*/
namespace HyperfTest\Database\PgSQL\Stubs;
use PHPUnit\Framework\Assert;
class SwooleVersionStub
{
public static function skipV6(): void
{
if (self::isV6()) {
Assert::markTestSkipped('The test is not compatible with swoole 6.0.0 or later.');
}
}
public static function isV6(): bool
{
return version_compare(swoole_version(), '6.x', '>=');
}
}

View File

@ -538,6 +538,30 @@ class Builder
return $this->join(new Expression($expression), $first, $operator, $second, $type, $where);
}
/**
* Add a lateral join clause to the query.
*/
public function joinLateral(Builder|Closure|ModelBuilder|string $query, string $as, string $type = 'inner'): static
{
[$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.
*/
public function leftJoinLateral(Builder|Closure|ModelBuilder|string $query, string $as): static
{
return $this->joinLateral($query, $as, 'left');
}
/**
* Add a left join to the query.
*
@ -2775,6 +2799,16 @@ class Builder
});
}
/**
* Get a new join lateral clause.
*
* @param string $table
*/
protected function newJoinLateralClause(self $parentQuery, string $type, Expression|string $table): JoinLateralClause
{
return new JoinLateralClause($parentQuery, $type, $table);
}
/**
* Determine if the value is a query builder instance or a Closure.
*

View File

@ -17,6 +17,7 @@ use Hyperf\Database\Grammar as BaseGrammar;
use Hyperf\Database\Query\Builder;
use Hyperf\Database\Query\Expression;
use Hyperf\Database\Query\JoinClause;
use Hyperf\Database\Query\JoinLateralClause;
use Hyperf\Stringable\Str;
use RuntimeException;
@ -347,6 +348,16 @@ class Grammar extends BaseGrammar
return $query;
}
/**
* Compile a "lateral join" clause.
*
* @throws RuntimeException
*/
public function compileJoinLateral(JoinLateralClause $join, string $expression): string
{
throw new RuntimeException('This database engine does not support lateral joins.');
}
/**
* Compile the components necessary for a select clause.
*/
@ -430,6 +441,10 @@ class Grammar extends BaseGrammar
$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(' ');
}

View File

@ -15,6 +15,7 @@ namespace Hyperf\Database\Query\Grammars;
use Hyperf\Collection\Arr;
use Hyperf\Database\Query\Builder;
use Hyperf\Database\Query\IndexHint;
use Hyperf\Database\Query\JoinLateralClause;
use Hyperf\Database\Query\JsonExpression;
use function Hyperf\Collection\collect;
@ -169,6 +170,14 @@ class MySqlGrammar extends Grammar
return parent::prepareBindingsForUpdate($bindings, $values);
}
/**
* Compile a "lateral join" clause.
*/
public function compileJoinLateral(JoinLateralClause $join, string $expression): string
{
return trim("{$join->type} join lateral {$expression} on true");
}
/**
* Compile a delete statement into SQL.
*/

View File

@ -0,0 +1,17 @@
<?php
declare(strict_types=1);
/**
* This file is part of Hyperf.
*
* @link https://www.hyperf.io
* @document https://hyperf.wiki
* @contact group@hyperf.io
* @license https://github.com/hyperf/hyperf/blob/master/LICENSE
*/
namespace Hyperf\Database\Query;
class JoinLateralClause extends JoinClause
{
}

View File

@ -907,6 +907,70 @@ class DatabaseQueryBuilderTest extends TestCase
$this->assertEquals(['%Taylor%', '%Otwell%', '%Otwell%'], $builder->getBindings());
}
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 = $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']);
}
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());
}
protected function getBuilder(): Builder
{
$grammar = new Grammar();

View File

@ -40,6 +40,7 @@ use Hyperf\Di\Container;
use Hyperf\Engine\Channel;
use Hyperf\Paginator\LengthAwarePaginator;
use Hyperf\Paginator\Paginator;
use Hyperf\Stringable\Str;
use Hyperf\Support\Reflection\ClassInvoker;
use HyperfTest\Database\Stubs\ContainerStub;
use HyperfTest\Database\Stubs\IntegerStatus;
@ -87,6 +88,8 @@ class ModelRealBuilderTest extends TestCase
$conn->statement('DROP TABLE IF EXISTS `test`;');
$conn->statement('DROP TABLE IF EXISTS `test_full_text_index`;');
$conn->statement('DROP TABLE IF EXISTS `test_enum_cast`;');
$conn->statement('DROP TABLE IF EXISTS `users`;');
$conn->statement('DROP TABLE IF EXISTS `posts`;');
Mockery::close();
}
@ -770,6 +773,85 @@ class ModelRealBuilderTest extends TestCase
$this->assertCount(6, $result);
}
public function testJoinLateral(): void
{
Schema::create('users', function (Blueprint $table) {
$table->id('id');
$table->string('name');
});
Schema::create('posts', function (Blueprint $table) {
$table->id('id');
$table->string('title');
$table->integer('rating');
$table->unsignedBigInteger('user_id');
});
$container = $this->getContainer();
$container->shouldReceive('get')->with(Db::class)->andReturn(new Db($container));
$mySqlVersion = Db::select('select version()')[0]->{'version()'} ?? '';
if (version_compare($mySqlVersion, '8.0.14', '<')) {
$this->markTestSkipped('Lateral joins are not supported on MySQL < 8.0.14' . __CLASS__);
}
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],
]);
$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);
$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);
}
public function testEnumCast()
{
$container = $this->getContainer();

View File

@ -13,9 +13,9 @@ declare(strict_types=1);
namespace Cases\PgSQL;
use Hyperf\DB\DB;
use HyperfTest\Database\PgSQL\Stubs\SwooleVersionStub;
use HyperfTest\DB\Cases\AbstractTestCase;
use PHPUnit\Framework\Attributes\CoversNothing;
use PHPUnit\Framework\Attributes\RequiresPhpExtension;
/**
* @internal
@ -24,9 +24,9 @@ use PHPUnit\Framework\Attributes\CoversNothing;
#[CoversNothing]
class PgSQLTest extends AbstractTestCase
{
#[RequiresPhpExtension('swoole', '< 6.0')]
public function testExecute()
{
SwooleVersionStub::skipV6();
$res = DB::connection('pgsql')->execute('INSERT INTO public.users (email, name) VALUES (?, ?);', ['l@hyperf.io', 'limx']);
$this->assertGreaterThan(0, $res);