From ec1b1cbf1a394140dc9e4c7bc7984787bc5b7402 Mon Sep 17 00:00:00 2001 From: amir Date: Wed, 30 Mar 2022 19:43:52 +0430 Subject: [PATCH 1/2] Add `whereJsonContainsKey` to query builder --- src/Illuminate/Database/Query/Builder.php | 51 ++++++++++ .../Database/Query/Grammars/Grammar.php | 29 ++++++ .../Database/Query/Grammars/MySqlGrammar.php | 13 +++ .../Query/Grammars/PostgresGrammar.php | 16 ++++ .../Query/Grammars/SqlServerGrammar.php | 16 ++++ tests/Database/DatabaseQueryBuilderTest.php | 94 +++++++++++++++++++ 6 files changed, 219 insertions(+) diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index f0015be7ebc3..01634d09c205 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -1776,6 +1776,57 @@ public function orWhereJsonDoesntContain($column, $value) return $this->whereJsonDoesntContain($column, $value, 'or'); } + /** + * Add a "where JSON contains key" clause to the query. + * + * @param string $column + * @param string $boolean + * @param bool $not + * @return $this + */ + public function whereJsonContainsKey($column, $boolean = 'and', $not = false) + { + $type = 'JsonContainsKey'; + + $this->wheres[] = compact('type', 'column', 'boolean', 'not'); + + return $this; + } + + /** + * Add an "or where JSON contains key" clause to the query. + * + * @param string $column + * @return $this + */ + public function orWhereJsonContainsKey($column) + { + return $this->whereJsonContainsKey($column, 'or'); + } + + /** + * Add a "where JSON not contains key" clause to the query. + * + * @param string $column + * @param string $boolean + * @return $this + */ + public function whereJsonDoesntContainKey($column, $boolean = 'and') + { + return $this->whereJsonContainsKey($column, $boolean, true); + } + + /** + * Add an "or where JSON not contains key" clause to the query. + * + * @param string $column + * @return $this + */ + public function orWhereJsonDoesntContainKey($column) + { + return $this->whereJsonDoesntContainKey($column, 'or'); + } + /** * Add a "where JSON length" clause to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index 6543200e4bea..985a7712cdd9 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -620,6 +620,35 @@ public function prepareBindingForJsonContains($binding) return json_encode($binding); } + /** + * Compile a "where JSON contains key" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereJsonContainsKey(Builder $query, $where) + { + $not = $where['not'] ? 'not ' : ''; + + return $not.$this->compileJsonContainsKey( + $where['column'] + ); + } + + /** + * Compile a "JSON contains key" statement into SQL. + * + * @param string $column + * @return string + * + * @throws \RuntimeException + */ + protected function compileJsonContainsKey($column) + { + throw new RuntimeException('This database engine does not support JSON contains key operations.'); + } + /** * Compile a "where JSON length" clause. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 404b3d5408b0..ccd9f72ff894 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -100,6 +100,19 @@ protected function compileJsonContains($column, $value) return 'json_contains('.$field.', '.$value.$path.')'; } + /** + * Compile a "JSON contains key" statement into SQL. + * + * @param string $column + * @return string + */ + protected function compileJsonContainsKey($column) + { + [$field, $path] = $this->wrapJsonFieldAndPath($column); + + return 'ifnull(json_contains_path('.$field.', \'one\''.$path.'), 0)'; + } + /** * Compile a "JSON length" statement into SQL. * diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index 6683e14452be..1867885e875f 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -215,6 +215,22 @@ protected function compileJsonContains($column, $value) return '('.$column.')::jsonb @> '.$value; } + /** + * Compile a "JSON contains key" statement into SQL. + * + * @param string $column + * @return string + */ + protected function compileJsonContainsKey($column) + { + $parts = explode('->', $column); + $key = "'".str_replace("'", "''", array_pop($parts))."'"; + + $column = str_replace('->>', '->', $this->wrap(implode('->', $parts))); + + return 'coalesce(('.$column.')::jsonb ?? '.$key.', false)'; + } + /** * Compile a "JSON length" statement into SQL. * diff --git a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php index e71705189a83..42251729dea5 100755 --- a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php @@ -165,6 +165,22 @@ public function prepareBindingForJsonContains($binding) return is_bool($binding) ? json_encode($binding) : $binding; } + /** + * Compile a "JSON contains key" statement into SQL. + * + * @param string $column + * @return string + */ + protected function compileJsonContainsKey($column) + { + $parts = explode('->', $column); + $key = "'".str_replace("'", "''", array_pop($parts))."'"; + + [$field, $path] = $this->wrapJsonFieldAndPath(implode('->', $parts)); + + return $key.' in (select [key] from openjson('.$field.$path.'))'; + } + /** * Compile a "JSON length" statement into SQL. * diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index eb773fea38f0..b04ffd875bba 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -4402,6 +4402,100 @@ public function testWhereJsonDoesntContainSqlServer() $this->assertEquals([1], $builder->getBindings()); } + public function testWhereJsonContainsKeyMySql() + { + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('users.options->languages'); + $this->assertSame('select * from `users` where ifnull(json_contains_path(`users`.`options`, \'one\', \'$."languages"\'), 0)', $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('options->language->primary'); + $this->assertSame('select * from `users` where ifnull(json_contains_path(`options`, \'one\', \'$."language"."primary"\'), 0)', $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonContainsKey('options->languages'); + $this->assertSame('select * from `users` where `id` = ? or ifnull(json_contains_path(`options`, \'one\', \'$."languages"\'), 0)', $builder->toSql()); + } + + public function testWhereJsonContainsKeyPostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('users.options->languages'); + $this->assertSame('select * from "users" where coalesce(("users"."options")::jsonb ?? \'languages\', false)', $builder->toSql()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('options->language->primary'); + $this->assertSame('select * from "users" where coalesce(("options"->\'language\')::jsonb ?? \'primary\', false)', $builder->toSql()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonContainsKey('options->languages'); + $this->assertSame('select * from "users" where "id" = ? or coalesce(("options")::jsonb ?? \'languages\', false)', $builder->toSql()); + } + + public function testWhereJsonContainsKeySqlite() + { + $this->expectException(RuntimeException::class); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('options->languages')->toSql(); + } + + public function testWhereJsonContainsKeySqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('users.options->languages'); + $this->assertSame('select * from [users] where \'languages\' in (select [key] from openjson([users].[options]))', $builder->toSql()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereJsonContainsKey('options->language->primary'); + $this->assertSame('select * from [users] where \'primary\' in (select [key] from openjson([options], \'$."language"\'))', $builder->toSql()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonContainsKey('options->languages'); + $this->assertSame('select * from [users] where [id] = ? or \'languages\' in (select [key] from openjson([options]))', $builder->toSql()); + } + + public function testWhereJsonDoesntContainKeyMySql() + { + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from `users` where not ifnull(json_contains_path(`options`, \'one\', \'$."languages"\'), 0)', $builder->toSql()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from `users` where `id` = ? or not ifnull(json_contains_path(`options`, \'one\', \'$."languages"\'), 0)', $builder->toSql()); + } + + public function testWhereJsonDoesntContainKeyPostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from "users" where not coalesce(("options")::jsonb ?? \'languages\', false)', $builder->toSql()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from "users" where "id" = ? or not coalesce(("options")::jsonb ?? \'languages\', false)', $builder->toSql()); + } + + public function testWhereJsonDoesntContainKeySqlite() + { + $this->expectException(RuntimeException::class); + + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages')->toSql(); + } + + public function testWhereJsonDoesntContainKeySqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from [users] where not \'languages\' in (select [key] from openjson([options]))', $builder->toSql()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages'); + $this->assertSame('select * from [users] where [id] = ? or not \'languages\' in (select [key] from openjson([options]))', $builder->toSql()); + } + public function testWhereJsonLengthMySql() { $builder = $this->getMySqlBuilder(); From 4b30587175eb7cddc452d19ffb4526abef287b76 Mon Sep 17 00:00:00 2001 From: Taylor Otwell Date: Thu, 31 Mar 2022 09:28:04 -0500 Subject: [PATCH 2/2] formatting --- src/Illuminate/Database/Query/Builder.php | 8 ++++---- .../Database/Query/Grammars/PostgresGrammar.php | 1 + .../Database/Query/Grammars/SqlServerGrammar.php | 1 + 3 files changed, 6 insertions(+), 4 deletions(-) diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 01634d09c205..91d82cd7c923 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -1777,7 +1777,7 @@ public function orWhereJsonDoesntContain($column, $value) } /** - * Add a "where JSON contains key" clause to the query. + * Add a clause that determines if a JSON path exists to the query. * * @param string $column * @param string $boolean @@ -1794,7 +1794,7 @@ public function whereJsonContainsKey($column, $boolean = 'and', $not = false) } /** - * Add an "or where JSON contains key" clause to the query. + * Add an "or" clause that determines if a JSON path exists to the query. * * @param string $column * @return $this @@ -1805,7 +1805,7 @@ public function orWhereJsonContainsKey($column) } /** - * Add a "where JSON not contains key" clause to the query. + * Add a clause that determines if a JSON path does not exist to the query. * * @param string $column * @param string $boolean @@ -1817,7 +1817,7 @@ public function whereJsonDoesntContainKey($column, $boolean = 'and') } /** - * Add an "or where JSON not contains key" clause to the query. + * Add an "or" clause that determines if a JSON path does not exist to the query. * * @param string $column * @return $this diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index 1867885e875f..b9878d8a390f 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -224,6 +224,7 @@ protected function compileJsonContains($column, $value) protected function compileJsonContainsKey($column) { $parts = explode('->', $column); + $key = "'".str_replace("'", "''", array_pop($parts))."'"; $column = str_replace('->>', '->', $this->wrap(implode('->', $parts))); diff --git a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php index 42251729dea5..745f2275dbf5 100755 --- a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php @@ -174,6 +174,7 @@ public function prepareBindingForJsonContains($binding) protected function compileJsonContainsKey($column) { $parts = explode('->', $column); + $key = "'".str_replace("'", "''", array_pop($parts))."'"; [$field, $path] = $this->wrapJsonFieldAndPath(implode('->', $parts));