Skip to content

Commit

Permalink
Add Builder::whereJsonLength()
Browse files Browse the repository at this point in the history
  • Loading branch information
staudenmeir committed Aug 1, 2018
1 parent 60995f6 commit 5e33a96
Show file tree
Hide file tree
Showing 6 changed files with 223 additions and 16 deletions.
43 changes: 43 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
56 changes: 56 additions & 0 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down Expand Up @@ -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.
*
Expand Down
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
15 changes: 15 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
32 changes: 16 additions & 16 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.'))';
}
Expand All @@ -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.
*
Expand Down Expand Up @@ -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.
*
Expand Down
78 changes: 78 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -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();
Expand Down

0 comments on commit 5e33a96

Please sign in to comment.