Skip to content

Commit

Permalink
Add support JSON columns in orderBy statement (#184)
Browse files Browse the repository at this point in the history
---------

Co-authored-by: Aleksei Gagarin <[email protected]>
  • Loading branch information
msmakouz and roxblnfk authored Apr 3, 2024
1 parent 18bce1d commit b13a232
Show file tree
Hide file tree
Showing 11 changed files with 120 additions and 0 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@

v2.10.0 (01.04.2024)
--------------------
- Add support **JSON** columns in **orderBy** statement by @msmakouz (#184)
- Add `mediumText` column type by @msmakouz (#178)
- Fix caching of SQL insert query with Fragment values by @msmakouz (#177)
- Fix detection of enum values in PostgreSQL when a enum field has only one value by @msmakouz (#181)
Expand Down
17 changes: 17 additions & 0 deletions src/Driver/Compiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -246,6 +246,10 @@ protected function orderBy(QueryParameters $params, Quoter $q, array $orderBy):
{
$result = [];
foreach ($orderBy as $order) {
if (\is_string($order[0]) && $this->isJsonPath($order[0])) {
$order[0] = $this->compileJsonOrderBy($order[0]);
}

if ($order[1] === null) {
$result[] = $this->name($params, $q, $order[0]);
continue;
Expand Down Expand Up @@ -531,6 +535,19 @@ protected function optional(string $prefix, string $expression, string $postfix
return $prefix . $expression . $postfix;
}

protected function isJsonPath(string $column): bool
{
return \str_contains($column, '->');
}

/**
* Each driver must override this method and implement sorting by JSON column.
*/
protected function compileJsonOrderBy(string $path): string|FragmentInterface
{
return $path;
}

private function arrayToInOperator(QueryParameters $params, Quoter $q, array $values, bool $in): string
{
$operator = $in ? 'IN' : 'NOT IN';
Expand Down
7 changes: 7 additions & 0 deletions src/Driver/MySQL/MySQLCompiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,9 @@

use Cycle\Database\Driver\CachingCompilerInterface;
use Cycle\Database\Driver\Compiler;
use Cycle\Database\Driver\MySQL\Injection\CompileJson;
use Cycle\Database\Driver\Quoter;
use Cycle\Database\Injection\FragmentInterface;
use Cycle\Database\Injection\Parameter;
use Cycle\Database\Query\QueryParameters;

Expand Down Expand Up @@ -69,4 +71,9 @@ protected function limit(QueryParameters $params, Quoter $q, int $limit = null,

return trim($statement);
}

protected function compileJsonOrderBy(string $path): FragmentInterface
{
return new CompileJson($path);
}
}
6 changes: 6 additions & 0 deletions src/Driver/Postgres/PostgresCompiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@

use Cycle\Database\Driver\CachingCompilerInterface;
use Cycle\Database\Driver\Compiler;
use Cycle\Database\Driver\Postgres\Injection\CompileJson;
use Cycle\Database\Driver\Quoter;
use Cycle\Database\Injection\FragmentInterface;
use Cycle\Database\Injection\Parameter;
Expand Down Expand Up @@ -87,4 +88,9 @@ protected function limit(QueryParameters $params, Quoter $q, int $limit = null,

return trim($statement);
}

protected function compileJsonOrderBy(string $path): FragmentInterface
{
return new CompileJson($path);
}
}
6 changes: 6 additions & 0 deletions src/Driver/SQLServer/SQLServerCompiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@

use Cycle\Database\Driver\Compiler;
use Cycle\Database\Driver\Quoter;
use Cycle\Database\Driver\SQLServer\Injection\CompileJson;
use Cycle\Database\Injection\Fragment;
use Cycle\Database\Injection\FragmentInterface;
use Cycle\Database\Injection\Parameter;
Expand Down Expand Up @@ -158,6 +159,11 @@ protected function limit(
return $statement;
}

protected function compileJsonOrderBy(string $path): FragmentInterface
{
return new CompileJson($path);
}

/**
* @inheritDoc
*/
Expand Down
7 changes: 7 additions & 0 deletions src/Driver/SQLite/SQLiteCompiler.php
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,9 @@
use Cycle\Database\Driver\CachingCompilerInterface;
use Cycle\Database\Driver\Compiler;
use Cycle\Database\Driver\Quoter;
use Cycle\Database\Driver\SQLite\Injection\CompileJson;
use Cycle\Database\Exception\CompilerException;
use Cycle\Database\Injection\FragmentInterface;
use Cycle\Database\Injection\Parameter;
use Cycle\Database\Injection\ParameterInterface;
use Cycle\Database\Query\QueryParameters;
Expand Down Expand Up @@ -121,4 +123,9 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens

return implode("\n", $statement);
}

protected function compileJsonOrderBy(string $path): FragmentInterface
{
return new CompileJson($path);
}
}
13 changes: 13 additions & 0 deletions tests/Database/Functional/Driver/MySQL/Query/SelectQueryTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -493,4 +493,17 @@ public function testOrderByCompileException(): void
->orderBy('name', 'FOO')
->sqlStatement();
}

public function testOrderByJson(): void
{
$select = $this->database
->select()
->from('table')
->orderBy('logs->created_at', 'DESC');

$this->assertSameQuery(
"SELECT * FROM {table} ORDER BY json_unquote(json_extract({logs}, '$.\"created_at\"')) DESC",
$select
);
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -503,4 +503,14 @@ public function testOrderByCompileException(): void
->orderBy('name', 'FOO')
->sqlStatement();
}

public function testOrderByJson(): void
{
$select = $this->database
->select()
->from('table')
->orderBy('logs->created_at', 'DESC');

$this->assertSameQuery("SELECT * FROM {table} ORDER BY {logs}->>'created_at' DESC", $select);
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -548,4 +548,17 @@ public function testSelectWithWhereJsonLengthNestedArray(): void
);
$this->assertSameParameters([5], $select);
}

public function testOrderByJson(): void
{
$select = $this->database
->select()
->from('table')
->orderBy('logs->created_at', 'DESC');

$this->assertSameQuery(
"SELECT * FROM {table} ORDER BY json_value({logs}, '$.\"created_at\"') DESC",
$select
);
}
}
13 changes: 13 additions & 0 deletions tests/Database/Functional/Driver/SQLite/Query/SelectQueryTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -328,4 +328,17 @@ public function testSelectWithWhereJsonLengthNestedArray(): void
);
$this->assertSameParameters([5], $select);
}

public function testOrderByJson(): void
{
$select = $this->database
->select()
->from('table')
->orderBy('logs->created_at', 'DESC');

$this->assertSameQuery(
"SELECT * FROM {table} ORDER BY json_extract({logs}, '$.\"created_at\"') DESC",
$select
);
}
}
27 changes: 27 additions & 0 deletions tests/Database/Unit/Driver/CompilerTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
<?php

declare(strict_types=1);

namespace Cycle\Database\Tests\Unit\Driver;

use Cycle\Database\Driver\Compiler;
use Cycle\Database\Driver\Quoter;
use Cycle\Database\Query\QueryParameters;
use PHPUnit\Framework\TestCase;

final class CompilerTest extends TestCase
{
public function testCompileJsonOrderByShouldReturnOriginalStatement(): void
{
$compiler = new class () extends Compiler {
protected function limit(QueryParameters $params, Quoter $q, int $limit = null, int $offset = null): string
{
}
};

$ref = new \ReflectionMethod($compiler, 'compileJsonOrderBy');
$ref->setAccessible(true);

$this->assertSame('foo-bar', $ref->invoke($compiler, 'foo-bar'));
}
}

0 comments on commit b13a232

Please sign in to comment.