Skip to content

Commit d80471d

Browse files
[9.x] Database queries containing JSON paths support array index braces, part 2 (#41767)
* Apply schema grammar fixes for JSON path array references Illuminate\Database\Query\Grammars\Grammar@wrapJsonFieldAndPath() and Illuminate\Database\Schema\Grammars\Grammar@wrapJsonFieldAndPath() were copy and pasted duplicates but the query version had JSON path fixes applied that the schema version doesn't have. Instead add a trait to make the two classes share these methods. * 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') * formatting Co-authored-by: Taylor Otwell <[email protected]>
1 parent 1d82ec6 commit d80471d

File tree

8 files changed

+256
-95
lines changed

8 files changed

+256
-95
lines changed
Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,64 @@
1+
<?php
2+
3+
namespace Illuminate\Database\Concerns;
4+
5+
use Illuminate\Support\Str;
6+
7+
trait CompilesJsonPaths
8+
{
9+
/**
10+
* Split the given JSON selector into the field and the optional path and wrap them separately.
11+
*
12+
* @param string $column
13+
* @return array
14+
*/
15+
protected function wrapJsonFieldAndPath($column)
16+
{
17+
$parts = explode('->', $column, 2);
18+
19+
$field = $this->wrap($parts[0]);
20+
21+
$path = count($parts) > 1 ? ', '.$this->wrapJsonPath($parts[1], '->') : '';
22+
23+
return [$field, $path];
24+
}
25+
26+
/**
27+
* Wrap the given JSON path.
28+
*
29+
* @param string $value
30+
* @param string $delimiter
31+
* @return string
32+
*/
33+
protected function wrapJsonPath($value, $delimiter = '->')
34+
{
35+
$value = preg_replace("/([\\\\]+)?\\'/", "''", $value);
36+
37+
$jsonPath = collect(explode($delimiter, $value))
38+
->map(fn ($segment) => $this->wrapJsonPathSegment($segment))
39+
->join('.');
40+
41+
return "'$".(str_starts_with($jsonPath, '[') ? '' : '.').$jsonPath."'";
42+
}
43+
44+
/**
45+
* Wrap the given JSON path segment.
46+
*
47+
* @param string $segment
48+
* @return string
49+
*/
50+
protected function wrapJsonPathSegment($segment)
51+
{
52+
if (preg_match('/(\[[^\]]+\])+$/', $segment, $parts)) {
53+
$key = Str::beforeLast($segment, $parts[0]);
54+
55+
if (! empty($key)) {
56+
return '"'.$key.'"'.$parts[0];
57+
}
58+
59+
return $parts[0];
60+
}
61+
62+
return '"'.$segment.'"';
63+
}
64+
}

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

Lines changed: 3 additions & 59 deletions
Original file line numberDiff line numberDiff line change
@@ -2,15 +2,17 @@
22

33
namespace Illuminate\Database\Query\Grammars;
44

5+
use Illuminate\Database\Concerns\CompilesJsonPaths;
56
use Illuminate\Database\Grammar as BaseGrammar;
67
use Illuminate\Database\Query\Builder;
78
use Illuminate\Database\Query\JoinClause;
89
use Illuminate\Support\Arr;
9-
use Illuminate\Support\Str;
1010
use RuntimeException;
1111

1212
class Grammar extends BaseGrammar
1313
{
14+
use CompilesJsonPaths;
15+
1416
/**
1517
* The grammar specific operators.
1618
*
@@ -1259,64 +1261,6 @@ protected function wrapJsonBooleanValue($value)
12591261
return $value;
12601262
}
12611263

1262-
/**
1263-
* Split the given JSON selector into the field and the optional path and wrap them separately.
1264-
*
1265-
* @param string $column
1266-
* @return array
1267-
*/
1268-
protected function wrapJsonFieldAndPath($column)
1269-
{
1270-
$parts = explode('->', $column, 2);
1271-
1272-
$field = $this->wrap($parts[0]);
1273-
1274-
$path = count($parts) > 1 ? ', '.$this->wrapJsonPath($parts[1], '->') : '';
1275-
1276-
return [$field, $path];
1277-
}
1278-
1279-
/**
1280-
* Wrap the given JSON path.
1281-
*
1282-
* @param string $value
1283-
* @param string $delimiter
1284-
* @return string
1285-
*/
1286-
protected function wrapJsonPath($value, $delimiter = '->')
1287-
{
1288-
$value = preg_replace("/([\\\\]+)?\\'/", "''", $value);
1289-
1290-
$jsonPath = collect(explode($delimiter, $value))
1291-
->map(function ($segment) {
1292-
return $this->wrapJsonPathSegment($segment);
1293-
})
1294-
->join('.');
1295-
1296-
return "'$".(str_starts_with($jsonPath, '[') ? '' : '.').$jsonPath."'";
1297-
}
1298-
1299-
/**
1300-
* Wrap the given JSON path segment.
1301-
*
1302-
* @param string $segment
1303-
* @return string
1304-
*/
1305-
protected function wrapJsonPathSegment($segment)
1306-
{
1307-
if (preg_match('/(\[[^\]]+\])+$/', $segment, $parts)) {
1308-
$key = Str::beforeLast($segment, $parts[0]);
1309-
1310-
if (! empty($key)) {
1311-
return '"'.$key.'"'.$parts[0];
1312-
}
1313-
1314-
return $parts[0];
1315-
}
1316-
1317-
return '"'.$segment.'"';
1318-
}
1319-
13201264
/**
13211265
* Concatenate an array of segments, removing empties.
13221266
*

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
}

src/Illuminate/Database/Schema/Grammars/Grammar.php

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

55
use Doctrine\DBAL\Schema\AbstractSchemaManager as SchemaManager;
66
use Doctrine\DBAL\Schema\TableDiff;
7+
use Illuminate\Database\Concerns\CompilesJsonPaths;
78
use Illuminate\Database\Connection;
89
use Illuminate\Database\Grammar as BaseGrammar;
910
use Illuminate\Database\Query\Expression;
@@ -14,6 +15,8 @@
1415

1516
abstract class Grammar extends BaseGrammar
1617
{
18+
use CompilesJsonPaths;
19+
1720
/**
1821
* If this Grammar supports schema changes wrapped in a transaction.
1922
*
@@ -273,37 +276,6 @@ public function wrapTable($table)
273276
);
274277
}
275278

276-
/**
277-
* Split the given JSON selector into the field and the optional path and wrap them separately.
278-
*
279-
* @param string $column
280-
* @return array
281-
*/
282-
protected function wrapJsonFieldAndPath($column)
283-
{
284-
$parts = explode('->', $column, 2);
285-
286-
$field = $this->wrap($parts[0]);
287-
288-
$path = count($parts) > 1 ? ', '.$this->wrapJsonPath($parts[1], '->') : '';
289-
290-
return [$field, $path];
291-
}
292-
293-
/**
294-
* Wrap the given JSON path.
295-
*
296-
* @param string $value
297-
* @param string $delimiter
298-
* @return string
299-
*/
300-
protected function wrapJsonPath($value, $delimiter = '->')
301-
{
302-
$value = preg_replace("/([\\\\]+)?\\'/", "''", $value);
303-
304-
return '\'$."'.str_replace($delimiter, '"."', $value).'"\'';
305-
}
306-
307279
/**
308280
* Wrap a value in keyword identifiers.
309281
*

tests/Database/DatabaseMySqlSchemaGrammarTest.php

Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1297,6 +1297,21 @@ public function testCreateTableWithVirtualAsColumn()
12971297
$this->assertSame("create table `users` (`my_json_column` varchar(255) not null, `my_other_column` varchar(255) as (json_unquote(json_extract(`my_json_column`, '$.\"some_attribute\".\"nested\"'))))", $statements[0]);
12981298
}
12991299

1300+
public function testCreateTableWithVirtualAsColumnWhenJsonColumnHasArrayKey()
1301+
{
1302+
$blueprint = new Blueprint('users');
1303+
$blueprint->create();
1304+
$blueprint->string('my_json_column')->virtualAsJson('my_json_column->foo[0][1]');
1305+
1306+
$conn = $this->getConnection();
1307+
$conn->shouldReceive('getConfig')->andReturn(null);
1308+
1309+
$statements = $blueprint->toSql($conn, $this->getGrammar());
1310+
1311+
$this->assertCount(1, $statements);
1312+
$this->assertSame("create table `users` (`my_json_column` varchar(255) as (json_unquote(json_extract(`my_json_column`, '$.\"foo\"[0][1]'))))", $statements[0]);
1313+
}
1314+
13001315
public function testCreateTableWithStoredAsColumn()
13011316
{
13021317
$conn = $this->getConnection();

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();

tests/Database/DatabaseSQLiteSchemaGrammarTest.php

Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -923,6 +923,21 @@ public function testCreateTableWithVirtualAsColumn()
923923
$this->assertSame('create table "users" ("my_json_column" varchar not null, "my_other_column" varchar as (json_extract("my_json_column", \'$."some_attribute"."nested"\')))', $statements[0]);
924924
}
925925

926+
public function testCreateTableWithVirtualAsColumnWhenJsonColumnHasArrayKey()
927+
{
928+
$blueprint = new Blueprint('users');
929+
$blueprint->create();
930+
$blueprint->string('my_json_column')->virtualAsJson('my_json_column->foo[0][1]');
931+
932+
$conn = $this->getConnection();
933+
$conn->shouldReceive('getConfig')->andReturn(null);
934+
935+
$statements = $blueprint->toSql($conn, $this->getGrammar());
936+
937+
$this->assertCount(1, $statements);
938+
$this->assertSame("create table \"users\" (\"my_json_column\" varchar as (json_extract(\"my_json_column\", '$.\"foo\"[0][1]')))", $statements[0]);
939+
}
940+
926941
public function testCreateTableWithStoredAsColumn()
927942
{
928943
$blueprint = new Blueprint('users');

0 commit comments

Comments
 (0)