From 5e33a96cd5fe9f5bea953a3e07ec827d5f19a9a3 Mon Sep 17 00:00:00 2001 From: Jonas Staudenmeir Date: Tue, 31 Jul 2018 20:37:08 +0200 Subject: [PATCH] Add Builder::whereJsonLength() --- src/Illuminate/Database/Query/Builder.php | 43 ++++++++++ .../Database/Query/Grammars/Grammar.php | 56 +++++++++++++ .../Database/Query/Grammars/MySqlGrammar.php | 15 ++++ .../Query/Grammars/PostgresGrammar.php | 15 ++++ .../Query/Grammars/SqlServerGrammar.php | 32 ++++---- tests/Database/DatabaseQueryBuilderTest.php | 78 +++++++++++++++++++ 6 files changed, 223 insertions(+), 16 deletions(-) diff --git a/src/Illuminate/Database/Query/Builder.php b/src/Illuminate/Database/Query/Builder.php index 5420f4c65dd5..8620ea5bea55 100755 --- a/src/Illuminate/Database/Query/Builder.php +++ b/src/Illuminate/Database/Query/Builder.php @@ -1492,6 +1492,49 @@ public function orWhereJsonDoesntContain($column, $value) return $this->whereJsonDoesntContain($column, $value, 'or'); } + /** + * Add a "where JSON length" clause to the query. + * + * @param string $column + * @param mixed $operator + * @param mixed $value + * @param string $boolean + * @return $this + */ + public function whereJsonLength($column, $operator, $value = null, $boolean = 'and') + { + $type = 'JsonLength'; + + list($value, $operator) = $this->prepareValueAndOperator( + $value, $operator, func_num_args() === 2 + ); + + $this->wheres[] = compact('type', 'column', 'operator', 'value', 'boolean'); + + if (! $value instanceof Expression) { + $this->addBinding($value); + } + + return $this; + } + + /** + * Add a "or where JSON length" clause to the query. + * + * @param string $column + * @param mixed $operator + * @param mixed $value + * @return $this + */ + public function orWhereJsonLength($column, $operator, $value = null) + { + list($value, $operator) = $this->prepareValueAndOperator( + $value, $operator, func_num_args() === 2 + ); + + return $this->whereJsonLength($column, $operator, $value, 'or'); + } + /** * Handles dynamic "where" clauses to the query. * diff --git a/src/Illuminate/Database/Query/Grammars/Grammar.php b/src/Illuminate/Database/Query/Grammars/Grammar.php index b9e002b2b9b2..4820f320c0a5 100755 --- a/src/Illuminate/Database/Query/Grammars/Grammar.php +++ b/src/Illuminate/Database/Query/Grammars/Grammar.php @@ -535,6 +535,34 @@ public function prepareBindingForJsonContains($binding) return json_encode($binding); } + /** + * Compile a "where JSON length" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + protected function whereJsonLength(Builder $query, $where) + { + return $this->compileJsonLength( + $where['column'], $where['operator'], $this->parameter($where['value']) + ); + } + + /** + * Compile a "JSON length" statement into SQL. + * + * @param string $column + * @param string $operator + * @param string $value + * @return string + * @throws \RuntimeException + */ + protected function compileJsonLength($column, $operator, $value) + { + throw new RuntimeException('This database engine does not support JSON length operations.'); + } + /** * Compile the "group by" portions of the query. * @@ -930,6 +958,34 @@ protected function wrapJsonSelector($value) throw new RuntimeException('This database engine does not support JSON operations.'); } + /** + * Split the given JSON selector into the field and the optional path and wrap them separately. + * + * @param string $column + * @return array + */ + protected function wrapJsonFieldAndPath($column) + { + $parts = explode('->', $column, 2); + + $field = $this->wrap($parts[0]); + + $path = count($parts) > 1 ? ', '.$this->wrapJsonPath($parts[1]) : ''; + + return [$field, $path]; + } + + /** + * Wrap the given JSON path. + * + * @param string $value + * @return string + */ + protected function wrapJsonPath($value) + { + return '\'$."'.str_replace('->', '"."', $value).'"\''; + } + /** * Determine if the given string is a JSON selector. * diff --git a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php index 38ac9cb3b43e..fce9a08519eb 100755 --- a/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/MySqlGrammar.php @@ -63,6 +63,21 @@ protected function compileJsonContains($column, $value) return 'json_contains('.$this->wrap($column).', '.$value.')'; } + /** + * Compile a "JSON length" statement into SQL. + * + * @param string $column + * @param string $operator + * @param string $value + * @return string + */ + protected function compileJsonLength($column, $operator, $value) + { + list($field, $path) = $this->wrapJsonFieldAndPath($column); + + return 'json_length('.$field.$path.') '.$operator.' '.$value; + } + /** * Compile a single union statement. * diff --git a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php index b41299a5d038..2a2f3bfb2b18 100755 --- a/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/PostgresGrammar.php @@ -77,6 +77,21 @@ protected function compileJsonContains($column, $value) return '('.$column.')::jsonb @> '.$value; } + /** + * Compile a "JSON length" statement into SQL. + * + * @param string $column + * @param string $operator + * @param string $value + * @return string + */ + protected function compileJsonLength($column, $operator, $value) + { + $column = str_replace('->>', '->', $this->wrap($column)); + + return 'json_array_length(('.$column.')::json) '.$operator.' '.$value; + } + /** * Compile the lock into SQL. * diff --git a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php index bb4809d67291..0583c4ae4719 100755 --- a/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php +++ b/src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php @@ -112,11 +112,7 @@ protected function whereDate(Builder $query, $where) */ protected function compileJsonContains($column, $value) { - $parts = explode('->', $column, 2); - - $field = $this->wrap($parts[0]); - - $path = count($parts) > 1 ? ', '.$this->wrapJsonPath($parts[1]) : ''; + list($field, $path) = $this->wrapJsonFieldAndPath($column); return $value.' in (select [value] from openjson('.$field.$path.'))'; } @@ -132,6 +128,21 @@ public function prepareBindingForJsonContains($binding) return is_bool($binding) ? json_encode($binding) : $binding; } + /** + * Compile a "JSON length" statement into SQL. + * + * @param string $column + * @param string $operator + * @param string $value + * @return string + */ + protected function compileJsonLength($column, $operator, $value) + { + list($field, $path) = $this->wrapJsonFieldAndPath($column); + + return '(select count(*) from openjson('.$field.$path.')) '.$operator.' '.$value; + } + /** * Create a full ANSI offset clause for the query. * @@ -458,17 +469,6 @@ protected function wrapJsonSelector($value) return 'json_value('.$field.', '.$this->wrapJsonPath($parts[0]).')'; } - /** - * Wrap the given JSON path. - * - * @param string $value - * @return string - */ - protected function wrapJsonPath($value) - { - return '\'$."'.str_replace('->', '"."', $value).'"\''; - } - /** * Wrap a table in keyword identifiers. * diff --git a/tests/Database/DatabaseQueryBuilderTest.php b/tests/Database/DatabaseQueryBuilderTest.php index 3b74507ad8a8..d612dc470ea9 100755 --- a/tests/Database/DatabaseQueryBuilderTest.php +++ b/tests/Database/DatabaseQueryBuilderTest.php @@ -2758,6 +2758,84 @@ public function testWhereJsonDoesntContainSqlServer() $this->assertEquals([1], $builder->getBindings()); } + public function testWhereJsonLengthMySql() + { + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereJsonLength('options', 0); + $this->assertEquals('select * from `users` where json_length(`options`) = ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->whereJsonLength('users.options->languages', '>', 0); + $this->assertEquals('select * from `users` where json_length(`users`.`options`, \'$."languages"\') > ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', new Raw('0')); + $this->assertEquals('select * from `users` where `id` = ? or json_length(`options`, \'$."languages"\') = 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + + $builder = $this->getMySqlBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', '>', new Raw('0')); + $this->assertEquals('select * from `users` where `id` = ? or json_length(`options`, \'$."languages"\') > 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + } + + public function testWhereJsonLengthPostgres() + { + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereJsonLength('options', 0); + $this->assertEquals('select * from "users" where json_array_length(("options")::json) = ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->whereJsonLength('users.options->languages', '>', 0); + $this->assertEquals('select * from "users" where json_array_length(("users"."options"->\'languages\')::json) > ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', new Raw('0')); + $this->assertEquals('select * from "users" where "id" = ? or json_array_length(("options"->\'languages\')::json) = 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + + $builder = $this->getPostgresBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', '>', new Raw('0')); + $this->assertEquals('select * from "users" where "id" = ? or json_array_length(("options"->\'languages\')::json) > 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + } + + /** + * @expectedException \RuntimeException + */ + public function testWhereJsonLengthSqlite() + { + $builder = $this->getSQLiteBuilder(); + $builder->select('*')->from('users')->whereJsonLength('options', 0)->toSql(); + } + + public function testWhereJsonLengthSqlServer() + { + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereJsonLength('options', 0); + $this->assertEquals('select * from [users] where (select count(*) from openjson([options])) = ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->whereJsonLength('users.options->languages', '>', 0); + $this->assertEquals('select * from [users] where (select count(*) from openjson([users].[options], \'$."languages"\')) > ?', $builder->toSql()); + $this->assertEquals([0], $builder->getBindings()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', new Raw('0')); + $this->assertEquals('select * from [users] where [id] = ? or (select count(*) from openjson([options], \'$."languages"\')) = 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + + $builder = $this->getSqlServerBuilder(); + $builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonLength('options->languages', '>', new Raw('0')); + $this->assertEquals('select * from [users] where [id] = ? or (select count(*) from openjson([options], \'$."languages"\')) > 0', $builder->toSql()); + $this->assertEquals([1], $builder->getBindings()); + } + public function testFromSub() { $builder = $this->getBuilder();