Skip to content

Commit

Permalink
sqlprocessor: implement spread modifier [closes #141]
Browse files Browse the repository at this point in the history
  • Loading branch information
hrach committed Oct 3, 2021
1 parent b18e3d0 commit 3b27281
Show file tree
Hide file tree
Showing 3 changed files with 65 additions and 17 deletions.
39 changes: 25 additions & 14 deletions docs/param-modifiers.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,20 +2,21 @@

Dbal allows you to escape and build safe SQL query. It provides these powerful parameter modifiers:

| Modifier | Type | Description
|-------------------------------|----------|------------
| `%s`, `%?s`, `%s[]` | string | not nullable, nullable, array of
| `%i`, `%?i`, `%i[]` | integer | not nullable, nullable, array of
| `%f`, `%?f`, `%f[]` | float | not nullable, nullable, array of
| `%b`, `%?b`, `%b[]` | boolean | not nullable, nullable, array of
| `%dt`, `%?dt`, `%dt[]` | datetime | not nullable, nullable, array of<br>read more about [datetime handling](datetime); using wrong modifier may damage your data
| `%ldt`, `%?ldt`, `%ldt[]` | local datetime | datetime without timezone conversion<br>read more about [datetime handling](datetime); using wrong modifier may damage your data
| `%blob`, `%?blob`, `%blob[]` | binary string | not nullable, nullable, array of
| `%any` | | any value
| `%_like`, `%like_`, `%_like_` | string | like left, like right, like both sides
| `%json`, `%?json`, `%json[]` | any | not nullable, nullable, array of

All modifiers require an argument of the specific data type - eg. `%f` accepts only floats and integers.
| Modifier | Type | Description
|--------------------------------------------|----------------|------------
| `%s`, `%?s`, `%s[]`, `%...s[]` | string | not nullable, nullable, array of
| `%i`, `%?i`, `%i[]`, `%...i[]` | integer | not nullable, nullable, array of
| `%f`, `%?f`, `%f[]`, `%...f[]` | float | not nullable, nullable, array of
| `%b`, `%?b`, `%b[]`, `%...b[]` | boolean | not nullable, nullable, array of
| `%dt`, `%?dt`, `%dt[]`, `%...dt[]` | datetime | not nullable, nullable, array of<br>read more about [datetime handling](datetime); using wrong modifier may damage your data
| `%ldt`, `%?ldt`, `%ldt[]`, `%...ldt[]` | local datetime | datetime without timezone conversion<br>read more about [datetime handling](datetime); using wrong modifier may damage your data
| `%di`, `%?di`, `%di[]`, `%...di[]` | date interval | DateInterval instance
| `%blob`, `%?blob`, `%blob[]` | binary string | not nullable, nullable, array of
| `%json`, `%?json`, `%json[]`, `%...json[]` | any | not nullable, nullable, array of
| `%any ` | | any value
| `%_like`, `%like_`, `%_like_` | string | like left, like right, like both sides

All modifiers require an argument of the specific data type - e.g. `%f` accepts only floats and integers.

```php
$connection->query('id = %i AND name IN (%?s, %?s)', 1, NULL, 'foo');
Expand All @@ -26,6 +27,16 @@ $connection->query('name LIKE %_like_', $query);
// name LIKE '%escaped query expression%'
```

Array modifiers are able to process array of the required type. The basic `[]` suffix syntax denotes such array. This way Dbal also adds wrapping parenthesis. You may want to omit them for more complex SQL. To do so, use a "spread" variant of array operator -- add three dots after the `%` character.

```php
$connection->query('WHERE id IN %i[]', [1, 3, 4]);
// WHERE `id` IN (1, 3, 4)

$connection->query('WHERE [roles.privileges] ?| ARRAY[%...s[]]', ['backend', 'frontend']);
// WHERE "roles"."privileges" ?| ARRAY['backend', 'frontend']
```

Other available modifiers:

| Modifier | Description
Expand Down
19 changes: 16 additions & 3 deletions src/SqlProcessor.php
Original file line number Diff line number Diff line change
Expand Up @@ -127,7 +127,7 @@ public function process(array $args): string

$i = $j;
$fragments[] = preg_replace_callback(
'#%(\??+\w++(?:\[\]){0,2}+)|(%%)|(\[\[)|(\]\])|\[(.+?)\]#S', // %modifier | %% | %[ | %] | [identifier]
'#%((?:\.\.\.)?+\??+\w++(?:\[]){0,2}+)|(%%)|(\[\[)|(]])|\[(.+?)]#S', // %modifier | %% | %[ | %] | [identifier]
function ($matches) use ($args, &$j, $last): string {
if ($matches[1] !== '') {
if ($j === $last) {
Expand Down Expand Up @@ -344,7 +344,9 @@ public function processModifier(string $type, $value): string

// normal
case 'column[]':
case '...column[]':
case 'table[]':
case '...table[]':
$subType = substr($type, 0, -2);
foreach ($value as &$subValue) {
$subValue = $this->processModifier($subType, $subValue);
Expand Down Expand Up @@ -379,7 +381,7 @@ public function processModifier(string $type, $value): string
}
}

$baseType = trim($type, '[]?');
$baseType = trim($type, '[]?.');

if (isset($this->customModifiers[$baseType])) {
return $this->customModifiers[$baseType]($this, $value, $type);
Expand Down Expand Up @@ -450,11 +452,22 @@ protected function throwWrongModifierException(string $type, $value, string $hin
protected function processArray(string $type, array $value): string
{
$subType = substr($type, 0, -2);
$wrapped = true;

if (strncmp($subType, '...', 3) === 0) {
$subType = substr($subType, 3);
$wrapped = false;
}

foreach ($value as &$subValue) {
$subValue = $this->processModifier($subType, $subValue);
}

return '(' . implode(', ', $value) . ')';
if ($wrapped) {
return '(' . implode(', ', $value) . ')';
} else {
return implode(', ', $value);
}
}


Expand Down
24 changes: 24 additions & 0 deletions tests/cases/unit/SqlProcessorTest.array.phpt
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,30 @@ class SqlProcessorArrayTest extends TestCase
}


public function testArraySpread()
{
Assert::same(
'SELECT FROM test WHERE id IN (1, 2, 3)',
$this->convert('SELECT FROM test WHERE id IN (%...i[])', [1, 2, 3])
);

Assert::same(
'SELECT FROM test WHERE id IN (1, 2, 3)',
$this->convert('SELECT FROM test WHERE id IN (%...i[])', ['foo' => 1, 12 => 2, 0 => 3])
);

Assert::same(
'SELECT FROM test WHERE id IN ()',
$this->convert('SELECT FROM test WHERE id IN (%...i[])', [])
);

Assert::same(
'SELECT FROM test WHERE id IN (NULL, 2, 3)',
$this->convert('SELECT FROM test WHERE id IN (%...?i[])', [null, 2, 3])
);
}


public function testWhereTuplets()
{
Assert::same(
Expand Down

0 comments on commit 3b27281

Please sign in to comment.