diff --git a/CHANGELOG.md b/CHANGELOG.md index c88711ab..c8c18fbc 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -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) diff --git a/src/Driver/Compiler.php b/src/Driver/Compiler.php index 3a68cdf1..b3a8b269 100644 --- a/src/Driver/Compiler.php +++ b/src/Driver/Compiler.php @@ -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; @@ -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'; diff --git a/src/Driver/MySQL/MySQLCompiler.php b/src/Driver/MySQL/MySQLCompiler.php index 22587e7a..bf8e5d48 100644 --- a/src/Driver/MySQL/MySQLCompiler.php +++ b/src/Driver/MySQL/MySQLCompiler.php @@ -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; @@ -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); + } } diff --git a/src/Driver/Postgres/PostgresCompiler.php b/src/Driver/Postgres/PostgresCompiler.php index 9df77d3e..133a1706 100644 --- a/src/Driver/Postgres/PostgresCompiler.php +++ b/src/Driver/Postgres/PostgresCompiler.php @@ -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; @@ -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); + } } diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index 9b3816b4..1931c013 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -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; @@ -158,6 +159,11 @@ protected function limit( return $statement; } + protected function compileJsonOrderBy(string $path): FragmentInterface + { + return new CompileJson($path); + } + /** * @inheritDoc */ diff --git a/src/Driver/SQLite/SQLiteCompiler.php b/src/Driver/SQLite/SQLiteCompiler.php index 882d3b80..7e1d5066 100644 --- a/src/Driver/SQLite/SQLiteCompiler.php +++ b/src/Driver/SQLite/SQLiteCompiler.php @@ -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; @@ -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); + } } diff --git a/tests/Database/Functional/Driver/MySQL/Query/SelectQueryTest.php b/tests/Database/Functional/Driver/MySQL/Query/SelectQueryTest.php index db07e969..9bc25674 100644 --- a/tests/Database/Functional/Driver/MySQL/Query/SelectQueryTest.php +++ b/tests/Database/Functional/Driver/MySQL/Query/SelectQueryTest.php @@ -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 + ); + } } diff --git a/tests/Database/Functional/Driver/Postgres/Query/SelectQueryTest.php b/tests/Database/Functional/Driver/Postgres/Query/SelectQueryTest.php index d9b83998..d7fa8fc5 100644 --- a/tests/Database/Functional/Driver/Postgres/Query/SelectQueryTest.php +++ b/tests/Database/Functional/Driver/Postgres/Query/SelectQueryTest.php @@ -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); + } } diff --git a/tests/Database/Functional/Driver/SQLServer/Query/SelectQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/SelectQueryTest.php index 33f9b959..541c641a 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/SelectQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/SelectQueryTest.php @@ -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 + ); + } } diff --git a/tests/Database/Functional/Driver/SQLite/Query/SelectQueryTest.php b/tests/Database/Functional/Driver/SQLite/Query/SelectQueryTest.php index 085fae9b..4840a224 100644 --- a/tests/Database/Functional/Driver/SQLite/Query/SelectQueryTest.php +++ b/tests/Database/Functional/Driver/SQLite/Query/SelectQueryTest.php @@ -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 + ); + } } diff --git a/tests/Database/Unit/Driver/CompilerTest.php b/tests/Database/Unit/Driver/CompilerTest.php new file mode 100644 index 00000000..0b446850 --- /dev/null +++ b/tests/Database/Unit/Driver/CompilerTest.php @@ -0,0 +1,27 @@ +setAccessible(true); + + $this->assertSame('foo-bar', $ref->invoke($compiler, 'foo-bar')); + } +}