Skip to content

Commit

Permalink
SqlPreprocessor: fixed bugs in WHERE
Browse files Browse the repository at this point in the history
  • Loading branch information
dg committed Dec 27, 2024
1 parent 5ad5c1e commit 9d5f814
Show file tree
Hide file tree
Showing 2 changed files with 26 additions and 24 deletions.
24 changes: 13 additions & 11 deletions src/Database/SqlPreprocessor.php
Original file line number Diff line number Diff line change
Expand Up @@ -312,34 +312,36 @@ private function formatAssigns(array $items): string
*/
private function formatWhere(array $items, string $mode): string
{
$default = '1=1';
$res = [];
foreach ($items as $k => $v) {
if (is_int($k)) {
$res[] = $this->formatValue($v);
continue;
}

[$k, $operator] = explode(' ', $k . ' ');
[$k, $operator] = explode(' ', $k, 2) + [1 => ''];
$k = $this->delimit($k);
if (is_array($v)) {
if ($v) {
$res[] = $k . ' ' . ($operator ? $operator . ' ' : '') . 'IN (' . $this->formatList(array_values($v)) . ')';
} elseif ($operator === 'NOT') {
$kind = ['' => true, 'IN' => true, 'NOT' => false, 'NOT IN' => false][$operator] ?? null;
if ($v || $kind === null) {
$res[] = $k . ' ' . ($kind === null ? $operator : ($kind ? 'IN' : 'NOT IN')) . ' (' . $this->formatList(array_values($v)) . ')';

} else {
$res[] = '1=0';
$default = $kind ? '1=0' : '1=1';
if ($kind === ($mode === self::ModeAnd)) {
return "($default)";
}
}

} else {
$v = $this->formatValue($v);
$operator = $v === 'NULL'
? ($operator === 'NOT' ? 'IS NOT' : ($operator ?: 'IS'))
: ($operator ?: '=');
$operator = ['' => ['=', 'IS'], 'NOT' => ['!=', 'IS NOT']][$operator][$v === 'NULL'] ?? $operator;
$res[] = $k . ' ' . $operator . ' ' . $v;
}
}

return $items
? '(' . implode(') ' . strtoupper($mode) . ' (', $res) . ')'
: '1=1';
return '(' . implode(') ' . strtoupper($mode) . ' (', $res ?: [$default]) . ')';
}


Expand Down
26 changes: 13 additions & 13 deletions tests/Database/SqlPreprocessor.phpt
Original file line number Diff line number Diff line change
Expand Up @@ -135,11 +135,11 @@ test('Auto-detects operator in WHERE conditions', function () use ($preprocessor

[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE', [
'col_null NOT' => null,
'x.col_val NOT' => 'a', // not supported
'x.col_val NOT' => 'a',
'col_arr NOT' => [1, 2],
]]);

Assert::same(reformat('SELECT id FROM tbl WHERE ([col_null] IS NOT NULL) AND ([x].[col_val] NOT ?) AND ([col_arr] NOT IN (?, ?))'), $sql);
Assert::same(reformat('SELECT id FROM tbl WHERE ([col_null] IS NOT NULL) AND ([x].[col_val] != ?) AND ([col_arr] NOT IN (?, ?))'), $sql);
});


Expand All @@ -148,12 +148,12 @@ test('Supports explicit operators in WHERE conditions', function () use ($prepro
'col_is =' => 1,
'col_not <>' => 1,
'col_like LIKE' => 'a',
'col_like NOT LIKE' => 'a', // not supported
'col_like NOT LIKE' => 'a',
'col_null =' => null, // always false
'col_arr =' => [1, 2], // not supported
'col_arr =' => [1, 2],
]]);

Assert::same(reformat('SELECT id FROM tbl WHERE ([col_is] = ?) AND ([col_not] <> ?) AND ([col_like] LIKE ?) AND ([col_like] NOT ?) AND ([col_null] = NULL) AND ([col_arr] = IN (?, ?))'), $sql);
Assert::same(reformat('SELECT id FROM tbl WHERE ([col_is] = ?) AND ([col_not] <> ?) AND ([col_like] LIKE ?) AND ([col_like] NOT LIKE ?) AND ([col_null] = NULL) AND ([col_arr] = (?, ?))'), $sql);
});


Expand All @@ -166,7 +166,7 @@ test('Redundant WHERE operators', function () use ($preprocessor) {
[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE', [
'col_arr NOT IN' => [],
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE ()'), $sql); // buggy
Assert::same(reformat('SELECT id FROM tbl WHERE (1=1)'), $sql);
});


Expand All @@ -175,7 +175,7 @@ test('Empty WHERE conditions', function () use ($preprocessor) {
'col_empty' => [],
'foo',
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE (1=0) AND (?)'), $sql);
Assert::same(reformat('SELECT id FROM tbl WHERE (1=0)'), $sql);

[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE', [
'col_empty' => [],
Expand All @@ -190,12 +190,12 @@ test('Empty WHERE conditions', function () use ($preprocessor) {
[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE', [
'col_empty NOT' => [],
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE ()'), $sql); // buggy
Assert::same(reformat('SELECT id FROM tbl WHERE (1=1)'), $sql);

[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE', [
'col_empty NOT IN' => [],
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE ()'), $sql); // buggy
Assert::same(reformat('SELECT id FROM tbl WHERE (1=1)'), $sql);
});


Expand All @@ -204,7 +204,7 @@ test('Empty WHERE conditions joined with OR', function () use ($preprocessor) {
'col_empty' => [],
new SqlLiteral('foo'),
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE (1=0) OR (foo)'), $sql);
Assert::same(reformat('SELECT id FROM tbl WHERE (foo)'), $sql);

[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE ?or', [
'col_empty' => [],
Expand All @@ -215,13 +215,13 @@ test('Empty WHERE conditions joined with OR', function () use ($preprocessor) {
'col_empty' => [],
'col_empty NOT' => [],
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE (1=0)'), $sql); // buggy
Assert::same(reformat('SELECT id FROM tbl WHERE (1=1)'), $sql);

[$sql, $params] = $preprocessor->process(['SELECT id FROM tbl WHERE ?or', [
'col_empty IN' => [],
'col_empty NOT IN' => [],
]]);
Assert::same(reformat('SELECT id FROM tbl WHERE (1=0)'), $sql); // buggy
Assert::same(reformat('SELECT id FROM tbl WHERE (1=1)'), $sql);
});


Expand Down Expand Up @@ -369,7 +369,7 @@ test('WHERE conditions with SQL literals', function () use ($preprocessor) {
test('empty WHERE conditions array', function () use ($preprocessor) {
[$sql, $params] = $preprocessor->process(['SELECT id FROM author WHERE', []]);

Assert::same(reformat('SELECT id FROM author WHERE 1=1'), $sql);
Assert::same(reformat('SELECT id FROM author WHERE (1=1)'), $sql);
Assert::same([], $params);
});

Expand Down

0 comments on commit 9d5f814

Please sign in to comment.