Skip to content

Commit ab59bf5

Browse files
committed
PostgresGrammar supports JSON array key braces
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')
1 parent 89a5363 commit ab59bf5

File tree

3 files changed

+156
-5
lines changed

3 files changed

+156
-5
lines changed

src/Illuminate/Database/Query/Grammars/PostgresGrammar.php

Lines changed: 33 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44

55
use Illuminate\Database\Query\Builder;
66
use Illuminate\Support\Arr;
7+
use Illuminate\Support\Str;
78

89
class PostgresGrammar extends Grammar
910
{
@@ -374,7 +375,7 @@ protected function compileJsonUpdateColumn($key, $value)
374375

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

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

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

625626
/**
626-
* Wrap the attributes of the give JSON path.
627+
* Wrap the attributes of the given JSON path.
627628
*
628629
* @param array $path
629630
* @return array
630631
*/
631632
protected function wrapJsonPathAttributes($path)
632633
{
633-
return array_map(function ($attribute) {
634+
$quote = func_num_args() === 2 ? func_get_arg(1) : "'";
635+
636+
return collect($path)->map(function ($attribute) {
637+
return $this->parseJsonPathArrayKeys($attribute);
638+
})->collapse()->map(function ($attribute) use ($quote) {
634639
return filter_var($attribute, FILTER_VALIDATE_INT) !== false
635640
? $attribute
636-
: "'$attribute'";
637-
}, $path);
641+
: $quote.$attribute.$quote;
642+
})->all();
643+
}
644+
645+
/**
646+
* Parse the given JSON path attribute for array keys.
647+
*
648+
* @param string $attribute
649+
* @return array
650+
*/
651+
protected function parseJsonPathArrayKeys($attribute)
652+
{
653+
if (preg_match('/(\[[^\]]+\])+$/', $attribute, $parts)) {
654+
$key = Str::beforeLast($attribute, $parts[0]);
655+
656+
preg_match_all('/\[([^\]]+)\]/', $parts[0], $keys);
657+
658+
return collect([$key])
659+
->merge($keys[1])
660+
->diff('')
661+
->values()
662+
->all();
663+
}
664+
665+
return [$attribute];
638666
}
639667
}

tests/Database/DatabaseQueryBuilderTest.php

Lines changed: 30 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3138,6 +3138,21 @@ public function testPostgresUpdateWrappingJsonArray()
31383138
]);
31393139
}
31403140

3141+
public function testPostgresUpdateWrappingJsonPathArrayIndex()
3142+
{
3143+
$builder = $this->getPostgresBuilder();
3144+
$builder->getConnection()->shouldReceive('update')
3145+
->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', [
3146+
'false',
3147+
'"large"',
3148+
]);
3149+
3150+
$builder->from('users')->where('options->[1]->2fa', true)->update([
3151+
'options->[1]->2fa' => false,
3152+
'meta->tags[0][2]' => 'large',
3153+
]);
3154+
}
3155+
31413156
public function testSQLiteUpdateWrappingJsonArray()
31423157
{
31433158
$builder = $this->getSQLiteBuilder();
@@ -3173,6 +3188,21 @@ public function testSQLiteUpdateWrappingNestedJsonArray()
31733188
]);
31743189
}
31753190

3191+
public function testSQLiteUpdateWrappingJsonPathArrayIndex()
3192+
{
3193+
$builder = $this->getSQLiteBuilder();
3194+
$builder->getConnection()->shouldReceive('update')
3195+
->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', [
3196+
'{"[1]":{"2fa":false}}',
3197+
'{"tags[0][2]":"large"}',
3198+
]);
3199+
3200+
$builder->from('users')->where('options->[1]->2fa', true)->update([
3201+
'options->[1]->2fa' => false,
3202+
'meta->tags[0][2]' => 'large',
3203+
]);
3204+
}
3205+
31763206
public function testMySqlWrappingJsonWithString()
31773207
{
31783208
$builder = $this->getMySqlBuilder();
Lines changed: 93 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,93 @@
1+
<?php
2+
3+
namespace Illuminate\Tests\Integration\Database\Postgres;
4+
5+
use Illuminate\Database\Schema\Blueprint;
6+
use Illuminate\Support\Facades\DB;
7+
use Illuminate\Support\Facades\Schema;
8+
9+
/**
10+
* @requires extension pdo_pgsql
11+
* @requires OS Linux|Darwin
12+
*/
13+
class DatabasePostgresConnectionTest extends PostgresTestCase
14+
{
15+
protected function defineDatabaseMigrationsAfterDatabaseRefreshed()
16+
{
17+
if (! Schema::hasTable('json_table')) {
18+
Schema::create('json_table', function (Blueprint $table) {
19+
$table->json('json_col')->nullable();
20+
});
21+
}
22+
}
23+
24+
protected function destroyDatabaseMigrations()
25+
{
26+
Schema::drop('json_table');
27+
}
28+
29+
/**
30+
* @dataProvider jsonWhereNullDataProvider
31+
*/
32+
public function testJsonWhereNull($expected, $key, array $value = ['value' => 123])
33+
{
34+
DB::table('json_table')->insert(['json_col' => json_encode($value)]);
35+
36+
$this->assertSame($expected, DB::table('json_table')->whereNull("json_col->$key")->exists());
37+
}
38+
39+
/**
40+
* @dataProvider jsonWhereNullDataProvider
41+
*/
42+
public function testJsonWhereNotNull($expected, $key, array $value = ['value' => 123])
43+
{
44+
DB::table('json_table')->insert(['json_col' => json_encode($value)]);
45+
46+
$this->assertSame(! $expected, DB::table('json_table')->whereNotNull("json_col->$key")->exists());
47+
}
48+
49+
public function jsonWhereNullDataProvider()
50+
{
51+
return [
52+
'key not exists' => [true, 'invalid'],
53+
'key exists and null' => [true, 'value', ['value' => null]],
54+
'key exists and "null"' => [false, 'value', ['value' => 'null']],
55+
'key exists and not null' => [false, 'value', ['value' => false]],
56+
'nested key not exists' => [true, 'nested->invalid'],
57+
'nested key exists and null' => [true, 'nested->value', ['nested' => ['value' => null]]],
58+
'nested key exists and "null"' => [false, 'nested->value', ['nested' => ['value' => 'null']]],
59+
'nested key exists and not null' => [false, 'nested->value', ['nested' => ['value' => false]]],
60+
'array index not exists' => [true, '[0]', [1 => 'invalid']],
61+
'array index exists and null' => [true, '[0]', [null]],
62+
'array index exists and "null"' => [false, '[0]', ['null']],
63+
'array index exists and not null' => [false, '[0]', [false]],
64+
'multiple array index not exists' => [true, '[0][0]', [1 => [1 => 'invalid']]],
65+
'multiple array index exists and null' => [true, '[0][0]', [[null]]],
66+
'multiple array index exists and "null"' => [false, '[0][0]', [['null']]],
67+
'multiple array index exists and not null' => [false, '[0][0]', [[false]]],
68+
'nested array index not exists' => [true, 'nested[0]', ['nested' => [1 => 'nested->invalid']]],
69+
'nested array index exists and null' => [true, 'nested->value[1]', ['nested' => ['value' => [0, null]]]],
70+
'nested array index exists and "null"' => [false, 'nested->value[1]', ['nested' => ['value' => [0, 'null']]]],
71+
'nested array index exists and not null' => [false, 'nested->value[1]', ['nested' => ['value' => [0, false]]]],
72+
];
73+
}
74+
75+
public function testJsonPathUpdate()
76+
{
77+
DB::table('json_table')->insert([
78+
['json_col' => '{"foo":["bar"]}'],
79+
['json_col' => '{"foo":["baz"]}'],
80+
['json_col' => '{"foo":[["array"]]}'],
81+
]);
82+
83+
$updatedCount = DB::table('json_table')->where('json_col->foo[0]', 'baz')->update([
84+
'json_col->foo[0]' => 'updated',
85+
]);
86+
$this->assertSame(1, $updatedCount);
87+
88+
$updatedCount = DB::table('json_table')->where('json_col->foo[0][0]', 'array')->update([
89+
'json_col->foo[0][0]' => 'updated',
90+
]);
91+
$this->assertSame(1, $updatedCount);
92+
}
93+
}

0 commit comments

Comments
 (0)