Skip to content

Commit

Permalink
PostgresGrammar supports JSON array key braces
Browse files Browse the repository at this point in the history
Similar to MySQL, SQL Server, and SQLite, make Postgres support
`$query->where('column->json_key[0]', 'foo')`. Postgres also allows
equivalent call `$query->where('column->json_key->0', 'foo')`.

Unlike the other database drivers, the SQL doesn't compile to a JSON
path expression. The array indices must be parsed from the string,
separating them into new segments. e.g.,

$query->where('column->json_key[0]', 'foo')
  • Loading branch information
derekmd committed Apr 1, 2022
1 parent 89a5363 commit ab59bf5
Show file tree
Hide file tree
Showing 3 changed files with 156 additions and 5 deletions.
38 changes: 33 additions & 5 deletions src/Illuminate/Database/Query/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@

use Illuminate\Database\Query\Builder;
use Illuminate\Support\Arr;
use Illuminate\Support\Str;

class PostgresGrammar extends Grammar
{
Expand Down Expand Up @@ -374,7 +375,7 @@ protected function compileJsonUpdateColumn($key, $value)

$field = $this->wrap(array_shift($segments));

$path = '\'{"'.implode('","', $segments).'"}\'';
$path = "'{".implode(',', $this->wrapJsonPathAttributes($segments, '"'))."}'";

return "{$field} = jsonb_set({$field}::jsonb, {$path}, {$this->parameter($value)})";
}
Expand Down Expand Up @@ -623,17 +624,44 @@ protected function wrapJsonBooleanValue($value)
}

/**
* Wrap the attributes of the give JSON path.
* Wrap the attributes of the given JSON path.
*
* @param array $path
* @return array
*/
protected function wrapJsonPathAttributes($path)
{
return array_map(function ($attribute) {
$quote = func_num_args() === 2 ? func_get_arg(1) : "'";

return collect($path)->map(function ($attribute) {
return $this->parseJsonPathArrayKeys($attribute);
})->collapse()->map(function ($attribute) use ($quote) {
return filter_var($attribute, FILTER_VALIDATE_INT) !== false
? $attribute
: "'$attribute'";
}, $path);
: $quote.$attribute.$quote;
})->all();
}

/**
* Parse the given JSON path attribute for array keys.
*
* @param string $attribute
* @return array
*/
protected function parseJsonPathArrayKeys($attribute)
{
if (preg_match('/(\[[^\]]+\])+$/', $attribute, $parts)) {
$key = Str::beforeLast($attribute, $parts[0]);

preg_match_all('/\[([^\]]+)\]/', $parts[0], $keys);

return collect([$key])
->merge($keys[1])
->diff('')
->values()
->all();
}

return [$attribute];
}
}
30 changes: 30 additions & 0 deletions tests/Database/DatabaseQueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -3138,6 +3138,21 @@ public function testPostgresUpdateWrappingJsonArray()
]);
}

public function testPostgresUpdateWrappingJsonPathArrayIndex()
{
$builder = $this->getPostgresBuilder();
$builder->getConnection()->shouldReceive('update')
->with('update "users" set "options" = jsonb_set("options"::jsonb, \'{1,"2fa"}\', ?), "meta" = jsonb_set("meta"::jsonb, \'{"tags",0,2}\', ?) where ("options"->1->\'2fa\')::jsonb = \'true\'::jsonb', [
'false',
'"large"',
]);

$builder->from('users')->where('options->[1]->2fa', true)->update([
'options->[1]->2fa' => false,
'meta->tags[0][2]' => 'large',
]);
}

public function testSQLiteUpdateWrappingJsonArray()
{
$builder = $this->getSQLiteBuilder();
Expand Down Expand Up @@ -3173,6 +3188,21 @@ public function testSQLiteUpdateWrappingNestedJsonArray()
]);
}

public function testSQLiteUpdateWrappingJsonPathArrayIndex()
{
$builder = $this->getSQLiteBuilder();
$builder->getConnection()->shouldReceive('update')
->with('update "users" set "options" = json_patch(ifnull("options", json(\'{}\')), json(?)), "meta" = json_patch(ifnull("meta", json(\'{}\')), json(?)) where json_extract("options", \'$[1]."2fa"\') = true', [
'{"[1]":{"2fa":false}}',
'{"tags[0][2]":"large"}',
]);

$builder->from('users')->where('options->[1]->2fa', true)->update([
'options->[1]->2fa' => false,
'meta->tags[0][2]' => 'large',
]);
}

public function testMySqlWrappingJsonWithString()
{
$builder = $this->getMySqlBuilder();
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,93 @@
<?php

namespace Illuminate\Tests\Integration\Database\Postgres;

use Illuminate\Database\Schema\Blueprint;
use Illuminate\Support\Facades\DB;
use Illuminate\Support\Facades\Schema;

/**
* @requires extension pdo_pgsql
* @requires OS Linux|Darwin
*/
class DatabasePostgresConnectionTest extends PostgresTestCase
{
protected function defineDatabaseMigrationsAfterDatabaseRefreshed()
{
if (! Schema::hasTable('json_table')) {
Schema::create('json_table', function (Blueprint $table) {
$table->json('json_col')->nullable();
});
}
}

protected function destroyDatabaseMigrations()
{
Schema::drop('json_table');
}

/**
* @dataProvider jsonWhereNullDataProvider
*/
public function testJsonWhereNull($expected, $key, array $value = ['value' => 123])
{
DB::table('json_table')->insert(['json_col' => json_encode($value)]);

$this->assertSame($expected, DB::table('json_table')->whereNull("json_col->$key")->exists());
}

/**
* @dataProvider jsonWhereNullDataProvider
*/
public function testJsonWhereNotNull($expected, $key, array $value = ['value' => 123])
{
DB::table('json_table')->insert(['json_col' => json_encode($value)]);

$this->assertSame(! $expected, DB::table('json_table')->whereNotNull("json_col->$key")->exists());
}

public function jsonWhereNullDataProvider()
{
return [
'key not exists' => [true, 'invalid'],
'key exists and null' => [true, 'value', ['value' => null]],
'key exists and "null"' => [false, 'value', ['value' => 'null']],
'key exists and not null' => [false, 'value', ['value' => false]],
'nested key not exists' => [true, 'nested->invalid'],
'nested key exists and null' => [true, 'nested->value', ['nested' => ['value' => null]]],
'nested key exists and "null"' => [false, 'nested->value', ['nested' => ['value' => 'null']]],
'nested key exists and not null' => [false, 'nested->value', ['nested' => ['value' => false]]],
'array index not exists' => [true, '[0]', [1 => 'invalid']],
'array index exists and null' => [true, '[0]', [null]],
'array index exists and "null"' => [false, '[0]', ['null']],
'array index exists and not null' => [false, '[0]', [false]],
'multiple array index not exists' => [true, '[0][0]', [1 => [1 => 'invalid']]],
'multiple array index exists and null' => [true, '[0][0]', [[null]]],
'multiple array index exists and "null"' => [false, '[0][0]', [['null']]],
'multiple array index exists and not null' => [false, '[0][0]', [[false]]],
'nested array index not exists' => [true, 'nested[0]', ['nested' => [1 => 'nested->invalid']]],
'nested array index exists and null' => [true, 'nested->value[1]', ['nested' => ['value' => [0, null]]]],
'nested array index exists and "null"' => [false, 'nested->value[1]', ['nested' => ['value' => [0, 'null']]]],
'nested array index exists and not null' => [false, 'nested->value[1]', ['nested' => ['value' => [0, false]]]],
];
}

public function testJsonPathUpdate()
{
DB::table('json_table')->insert([
['json_col' => '{"foo":["bar"]}'],
['json_col' => '{"foo":["baz"]}'],
['json_col' => '{"foo":[["array"]]}'],
]);

$updatedCount = DB::table('json_table')->where('json_col->foo[0]', 'baz')->update([
'json_col->foo[0]' => 'updated',
]);
$this->assertSame(1, $updatedCount);

$updatedCount = DB::table('json_table')->where('json_col->foo[0][0]', 'array')->update([
'json_col->foo[0][0]' => 'updated',
]);
$this->assertSame(1, $updatedCount);
}
}

0 comments on commit ab59bf5

Please sign in to comment.