Skip to content

Commit

Permalink
Add query builder method whereJsonContainsKey()
Browse files Browse the repository at this point in the history
Allow filtering by JSONB documents that contain a given object string
key or an array integer key.
  • Loading branch information
amir9480 authored and derekmd committed Apr 3, 2022
1 parent 71bb397 commit 3c0398f
Show file tree
Hide file tree
Showing 12 changed files with 500 additions and 0 deletions.
51 changes: 51 additions & 0 deletions src/Illuminate/Database/Query/Builder.php
Original file line number Diff line number Diff line change
Expand Up @@ -1776,6 +1776,57 @@ public function orWhereJsonDoesntContain($column, $value)
return $this->whereJsonDoesntContain($column, $value, 'or');
}

/**
* Add a clause that determines if a JSON path exists 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" clause that determines if a JSON path exists to the query.
*
* @param string $column
* @return $this
*/
public function orWhereJsonContainsKey($column)
{
return $this->whereJsonContainsKey($column, 'or');
}

/**
* Add a clause that determines if a JSON path does not exist 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" clause that determines if a JSON path does not exist 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.
*
Expand Down
29 changes: 29 additions & 0 deletions src/Illuminate/Database/Query/Grammars/Grammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -622,6 +622,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.
*
Expand Down
13 changes: 13 additions & 0 deletions src/Illuminate/Database/Query/Grammars/MySqlGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand Down
32 changes: 32 additions & 0 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -216,6 +216,38 @@ 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)
{
$segments = explode('->', $column);
$lastSegment = array_pop($segments);

if (filter_var($lastSegment, FILTER_VALIDATE_INT) !== false) {
$i = $lastSegment;
} elseif (preg_match('/\[(-?[0-9]+)\]$/', $lastSegment, $matches)) {
$segments[] = Str::beforeLast($lastSegment, $matches[0]);
$i = $matches[1];
}

$column = str_replace('->>', '->', $this->wrap(implode('->', $segments)));

if (isset($i)) {
return vsprintf('case when %s then %s else false end', [
'jsonb_typeof(('.$column.")::jsonb) = 'array'",
'jsonb_array_length(('.$column.')::jsonb) >= '.($i < 0 ? abs($i) : $i + 1),
]);
}

$key = "'".str_replace("'", "''", $lastSegment)."'";

return 'coalesce(('.$column.')::jsonb ?? '.$key.', false)';
}

/**
* Compile a "JSON length" statement into SQL.
*
Expand Down
13 changes: 13 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SQLiteGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -132,6 +132,19 @@ protected function compileJsonLength($column, $operator, $value)
return 'json_array_length('.$field.$path.') '.$operator.' '.$value;
}

/**
* Compile a "JSON contains key" statement into SQL.
*
* @param string $column
* @return string
*/
protected function compileJsonContainsKey($column)
{
[$field, $path] = $this->wrapJsonFieldAndPath($column);

return 'json_type('.$field.$path.') is not null';
}

/**
* Compile an update statement into SQL.
*
Expand Down
23 changes: 23 additions & 0 deletions src/Illuminate/Database/Query/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -165,6 +165,29 @@ 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)
{
$segments = explode('->', $column);
$lastSegment = array_pop($segments);

if (preg_match('/\[([0-9]+)\]$/', $lastSegment, $matches)) {
$segments[] = Str::beforeLast($lastSegment, $matches[0]);
$key = $matches[1];
} else {
$key = "'".str_replace("'", "''", $lastSegment)."'";
}

[$field, $path] = $this->wrapJsonFieldAndPath(implode('->', $segments));

return $key.' in (select [key] from openjson('.$field.$path.'))';
}

/**
* Compile a "JSON length" statement into SQL.
*
Expand Down
144 changes: 144 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -4432,6 +4432,150 @@ 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());

$builder = $this->getMySqlBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->languages[0][1]');
$this->assertSame('select * from `users` where ifnull(json_contains_path(`options`, \'one\', \'$."languages"[0][1]\'), 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());

$builder = $this->getPostgresBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->languages[0][1]');
$this->assertSame('select * from "users" where case when jsonb_typeof(("options"->\'languages\'->0)::jsonb) = \'array\' then jsonb_array_length(("options"->\'languages\'->0)::jsonb) >= 2 else false end', $builder->toSql());

$builder = $this->getPostgresBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->languages[-1]');
$this->assertSame('select * from "users" where case when jsonb_typeof(("options"->\'languages\')::jsonb) = \'array\' then jsonb_array_length(("options"->\'languages\')::jsonb) >= 1 else false end', $builder->toSql());
}

public function testWhereJsonContainsKeySqlite()
{
$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('users.options->languages');
$this->assertSame('select * from "users" where json_type("users"."options", \'$."languages"\') is not null', $builder->toSql());

$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->language->primary');
$this->assertSame('select * from "users" where json_type("options", \'$."language"."primary"\') is not null', $builder->toSql());

$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonContainsKey('options->languages');
$this->assertSame('select * from "users" where "id" = ? or json_type("options", \'$."languages"\') is not null', $builder->toSql());

$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->languages[0][1]');
$this->assertSame('select * from "users" where json_type("options", \'$."languages"[0][1]\') is not null', $builder->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());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->whereJsonContainsKey('options->languages[0][1]');
$this->assertSame('select * from [users] where 1 in (select [key] from openjson([options], \'$."languages"[0]\'))', $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());

$builder = $this->getMySqlBuilder();
$builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages[0][1]');
$this->assertSame('select * from `users` where not ifnull(json_contains_path(`options`, \'one\', \'$."languages"[0][1]\'), 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());

$builder = $this->getPostgresBuilder();
$builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages[0][1]');
$this->assertSame('select * from "users" where not case when jsonb_typeof(("options"->\'languages\'->0)::jsonb) = \'array\' then jsonb_array_length(("options"->\'languages\'->0)::jsonb) >= 2 else false end', $builder->toSql());

$builder = $this->getPostgresBuilder();
$builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages[-1]');
$this->assertSame('select * from "users" where not case when jsonb_typeof(("options"->\'languages\')::jsonb) = \'array\' then jsonb_array_length(("options"->\'languages\')::jsonb) >= 1 else false end', $builder->toSql());
}

public function testWhereJsonDoesntContainKeySqlite()
{
$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->whereJsonDoesntContainKey('options->languages');
$this->assertSame('select * from "users" where not json_type("options", \'$."languages"\') is not null', $builder->toSql());

$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages');
$this->assertSame('select * from "users" where "id" = ? or not json_type("options", \'$."languages"\') is not null', $builder->toSql());

$builder = $this->getSQLiteBuilder();
$builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages[0][1]');
$this->assertSame('select * from "users" where "id" = ? or not json_type("options", \'$."languages"[0][1]\') is not null', $builder->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());

$builder = $this->getSqlServerBuilder();
$builder->select('*')->from('users')->where('id', '=', 1)->orWhereJsonDoesntContainKey('options->languages[0][1]');
$this->assertSame('select * from [users] where [id] = ? or not 1 in (select [key] from openjson([options], \'$."languages"[0]\'))', $builder->toSql());
}

public function testWhereJsonLengthMySql()
{
$builder = $this->getMySqlBuilder();
Expand Down
28 changes: 28 additions & 0 deletions tests/Integration/Database/MySql/DatabaseMySqlConnectionTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -121,4 +121,32 @@ public function testJsonPathUpdate()
]);
$this->assertSame(1, $updatedCount);
}

/**
* @dataProvider jsonContainsKeyDataProvider
*/
public function testWhereJsonContainsKey($count, $column)
{
DB::table(self::TABLE)->insert([
['json_col' => '{"foo":{"bar":["baz"]}}'],
['json_col' => '{"foo":{"bar":false}}'],
['json_col' => '{"foo":{}}'],
['json_col' => '{"foo":[{"bar":"bar"},{"baz":"baz"}]}'],
]);

$this->assertSame($count, DB::table(self::TABLE)->whereJsonContainsKey($column)->count());
}

public function jsonContainsKeyDataProvider()
{
return [
'string key' => [4, 'json_col->foo'],
'nested key exists' => [2, 'json_col->foo->bar'],
'string key missing' => [0, 'json_col->none'],
'integer key with arrow ' => [0, 'json_col->foo->bar->0'],
'integer key with braces' => [2, 'json_col->foo->bar[0]'],
'integer key missing' => [0, 'json_col->foo->bar[1]'],
'mixed keys' => [1, 'json_col->foo[1]->baz'],
];
}
}
Loading

0 comments on commit 3c0398f

Please sign in to comment.