Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix numeric compare affinity for SQLite #989

Merged
merged 3 commits into from
Nov 15, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion phpstan.neon.dist
Original file line number Diff line number Diff line change
Expand Up @@ -40,7 +40,7 @@ parameters:
-
message: '~^Class Doctrine\\DBAL\\Platforms\\SqlitePlatform referenced with incorrect case: Doctrine\\DBAL\\Platforms\\SQLitePlatform\.$~'
path: '*'
count: 28
count: 25

# TODO these rules are generated, this ignores should be fixed in the code
# for src/Schema/TestCase.php
Expand Down
22 changes: 20 additions & 2 deletions src/Persistence/Sql/Query.php
Original file line number Diff line number Diff line change
Expand Up @@ -501,6 +501,24 @@ protected function _subrenderWhere($kind): array
return $res;
}

/**
* Override to fix numeric affinity for SQLite.
*/
protected function _renderConditionBinary(string $operator, string $sqlLeft, string $sqlRight): string
{
return $sqlLeft . ' ' . $operator . ' ' . $sqlRight;
}

/**
* Override to fix numeric affinity for SQLite.
*
* @param non-empty-list<string> $sqlValues
*/
protected function _renderConditionInOperator(bool $negated, string $sqlLeft, array $sqlValues): string
{
return $sqlLeft . ($negated ? ' not' : '') . ' in (' . implode(', ', $sqlValues) . ')';
}

/**
* @param array<0|1|2, mixed> $row
*/
Expand Down Expand Up @@ -575,7 +593,7 @@ protected function _subrenderCondition(array $row): string

$values = array_map(fn ($v) => $this->consume($v, self::ESCAPE_PARAM), $value);

return $field . ' ' . $cond . ' (' . implode(', ', $values) . ')';
return $this->_renderConditionInOperator($cond === 'not in', $field, $values);
}

throw (new Exception('Unsupported operator for array value'))
Expand All @@ -589,7 +607,7 @@ protected function _subrenderCondition(array $row): string
// otherwise just escape value
$value = $this->consume($value, self::ESCAPE_PARAM);

return $field . ' ' . $cond . ' ' . $value;
return $this->_renderConditionBinary($cond, $field, $value);
}

protected function _renderWhere(): ?string
Expand Down
51 changes: 51 additions & 0 deletions src/Persistence/Sql/Sqlite/Query.php
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,57 @@ class Query extends BaseQuery

protected string $templateTruncate = 'delete [from] [tableNoalias]';

private function _renderConditionBinaryCheckNumericSql(string $sql): string
{
return 'typeof(' . $sql . ') in (\'integer\', \'real\')';
}

/**
* https://dba.stackexchange.com/questions/332585/sqlite-comparison-of-the-same-operand-types-behaves-differently
* https://sqlite.org/forum/forumpost/5f1135146fbc37ab .
*/
protected function _renderConditionBinary(string $operator, string $sqlLeft, string $sqlRight): string
{
// TODO deduplicate the duplicated SQL using https://sqlite.org/forum/info/c9970a37edf11cd1
// https://github.com/sqlite/sqlite/commit/5e4233a9e48b124d4d342b757b34e4ae849f5cf8
// expected to be supported since SQLite v3.45.0

/** @var bool */
$allowCastLeft = true;
$allowCastRight = !in_array($operator, ['in', 'not in'], true);

$res = '';
if ($allowCastLeft) {
$res .= 'case when ' . $this->_renderConditionBinaryCheckNumericSql($sqlLeft)
. ' then ' . parent::_renderConditionBinary($operator, 'cast(' . $sqlLeft . ' as numeric)', $sqlRight)
. ' else ';
}
if ($allowCastRight) {
$res .= 'case when ' . $this->_renderConditionBinaryCheckNumericSql($sqlRight)
. ' then ' . parent::_renderConditionBinary($operator, $sqlLeft, 'cast(' . $sqlRight . ' as numeric)')
. ' else ';
}
$res .= parent::_renderConditionBinary($operator, $sqlLeft, $sqlRight);
if ($allowCastRight) {
$res .= ' end';
}
if ($allowCastLeft) {
$res .= ' end';
}

return $res;
}

protected function _renderConditionInOperator(bool $negated, string $sqlLeft, array $sqlValues): string
{
$res = '(' . implode(' or ', array_map(fn ($v) => $this->_renderConditionBinary('=', $sqlLeft, $v), $sqlValues)) . ')';
if ($negated) {
$res = 'not' . $res;
}

return $res;
}

public function groupConcat($field, string $separator = ',')
{
return $this->expr('group_concat({}, [])', [$field, $separator]);
Expand Down
10 changes: 10 additions & 0 deletions src/Schema/TestCase.php
Original file line number Diff line number Diff line change
Expand Up @@ -169,6 +169,16 @@ static function ($matches) use ($platform) {

protected function assertSameSql(string $expectedSqliteSql, string $actualSql, string $message = ''): void
{
// remove once SQLite affinity of expressions is fixed natively
// related with Atk4\Data\Persistence\Sql\Sqlite\Query::_renderConditionBinary() fix
if ($this->getDatabasePlatform() instanceof SQLitePlatform) {
do {
$actualSqlPrev = $actualSql;
$actualSql = preg_replace('~case when typeof\((.+?)\) in \(\'integer\', \'real\'\) then cast\(\1 as numeric\) (.{1,20}?) (.+?) else \1 \2 \3 end~s', '$1 $2 $3', $actualSql);
$actualSql = preg_replace('~case when typeof\((.+?)\) in \(\'integer\', \'real\'\) then (.+?) (.{1,20}?) cast\(\1 as numeric\) else \2 \3 \1 end~s', '$2 $3 $1', $actualSql);
} while ($actualSql !== $actualSqlPrev);
}

self::assertSame($this->convertSqlFromSqlite($expectedSqliteSql), $actualSql, $message);
}

Expand Down
11 changes: 3 additions & 8 deletions tests/ModelAggregateTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,6 @@
use Atk4\Data\Model\Scope;
use Atk4\Data\Model\Scope\Condition;
use Atk4\Data\Schema\TestCase;
use Doctrine\DBAL\Platforms\SQLitePlatform;

class ModelAggregateTest extends TestCase
{
Expand Down Expand Up @@ -177,8 +176,7 @@ public function testGroupSelectCondition2(): void
$aggregate->addCondition(
'double',
'>',
// TODO Sqlite bind param does not work, expr needed, even if casted to float with DBAL type (comparison works only if casted to/bind as int)
$this->getDatabasePlatform() instanceof SQLitePlatform ? $aggregate->expr('10') : 10
10
);

self::assertSame([
Expand All @@ -200,8 +198,7 @@ public function testGroupSelectCondition3(): void
$aggregate->addExpression('double', ['expr' => '[s] + [amount]', 'type' => 'atk4_money']);
$aggregate->addCondition(
'double',
// TODO Sqlite bind param does not work, expr needed, even if casted to float with DBAL type (comparison works only if casted to/bind as int)
$this->getDatabasePlatform() instanceof SQLitePlatform ? $aggregate->expr('38') : 38
38
);

self::assertSame([
Expand Down Expand Up @@ -238,9 +235,7 @@ public function testGroupSelectScope(): void
]);
self::fixAllNonAggregatedFieldsInGroupBy($aggregate);

// TODO Sqlite bind param does not work, expr needed, even if casted to float with DBAL type (comparison works only if casted to/bind as int)
$numExpr = $this->getDatabasePlatform() instanceof SQLitePlatform ? $aggregate->expr('4') : 4;
$scope = Scope::createAnd(new Condition('client_id', 2), new Condition('amount', $numExpr));
$scope = Scope::createAnd(new Condition('client_id', 2), new Condition('amount', 4));
$aggregate->addCondition($scope);

self::assertSame([
Expand Down
37 changes: 24 additions & 13 deletions tests/Persistence/Sql/WithDb/SelectTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -251,7 +251,7 @@ public function testWhereExpression(): void
* @param array{string, array<mixed>} $exprLeft
* @param array{string, array<mixed>} $exprRight
*/
public function testWhereNumericCompare(array $exprLeft, string $operator, array $exprRight, bool $expectPostgresqlTypeMismatchException = false, bool $expectMssqlTypeMismatchException = false, bool $expectSqliteWrongAffinity = false): void
public function testWhereNumericCompare(array $exprLeft, string $operator, array $exprRight, bool $expectPostgresqlTypeMismatchException = false, bool $expectMssqlTypeMismatchException = false): void
{
if ($this->getDatabasePlatform() instanceof OraclePlatform) {
$exprLeft[0] = preg_replace('~\d+[eE][\-+]?\d++~', '$0d', $exprLeft[0]);
Expand All @@ -272,14 +272,27 @@ public function testWhereNumericCompare(array $exprLeft, string $operator, array
}
$queryHaving->having($this->e(...$exprLeft), $operator, $this->e(...$exprRight));

$queryWhere2 = $this->q()->field($this->e('1'), 'v');
$queryWhere2->table($this->q()->field($this->e(...$exprLeft), 'a')->field($this->e(...$exprRight), 'b'), 't');
$queryWhere2->where('a', $operator, $this->e('{}', ['b']));
$queryWhereSub = $this->q()->field($this->e('1'), 'v');
$queryWhereSub->table($this->q()->field($this->e(...$exprLeft), 'a')->field($this->e(...$exprRight), 'b'), 't');
$queryWhereSub->where('a', $operator, $this->e('{}', ['b']));

$queryWhereIn = $this->q()->field($this->e('1'), 'v');
if ($this->getDatabasePlatform() instanceof MySQLPlatform) {
$queryWhereIn->table('(select 1)', 'dual'); // needed for MySQL 5.x when WHERE or HAVING is specified
}
if ($operator === '=' || $operator === '!=') {
$queryWhereIn->where(
$this->e(...$exprLeft),
$operator === '!=' ? 'not in' : 'in',
[$this->e(...$exprRight), $this->e(...$exprRight)]
);
}

$queryAll = $this->q()
->field($queryWhere, 'where')
->field($queryHaving, 'having')
->field($queryWhere2, 'where2');
->field($queryWhereSub, 'where_sub')
->field($queryWhereIn, 'where_in');

if (($expectPostgresqlTypeMismatchException && $this->getDatabasePlatform() instanceof PostgreSQLPlatform) || ($expectMssqlTypeMismatchException && $this->getDatabasePlatform() instanceof SQLServerPlatform)) {
$this->expectException(ExecuteException::class);
Expand All @@ -299,9 +312,7 @@ public function testWhereNumericCompare(array $exprLeft, string $operator, array
}

self::assertSame(
$expectSqliteWrongAffinity && $this->getDatabasePlatform() instanceof SQLitePlatform
? [['where' => null, 'having' => null, 'where2' => null]]
: [['where' => '1', 'having' => '1', 'where2' => '1']],
[['where' => '1', 'having' => '1', 'where_sub' => '1', 'where_in' => '1']],
$rows
);
}
Expand Down Expand Up @@ -361,11 +372,11 @@ public function provideWhereNumericCompareCases(): iterable
yield [['[]', [false]], '!=', ['[]', [true]]];
yield [['[]', [false]], '<', ['[]', [true]]];

yield [['4'], '=', ['[]', ['04']], true, false, true];
yield [['4'], '=', ['[]', ['04']], true];
yield [['\'04\''], '=', ['[]', [4]], true];
yield [['4'], '=', ['[]', [4.0]]];
yield [['4'], '=', ['[]', ['4.0']], true, true, true];
yield [['2.5'], '=', ['[]', ['02.50']], true, false, true];
yield [['4'], '=', ['[]', ['4.0']], true, true];
yield [['2.5'], '=', ['[]', ['02.50']], true];
yield [['0'], '=', ['[]', [false]], true];
yield [['0'], '!=', ['[]', [true]], true];
yield [['1'], '=', ['[]', [true]], true];
Expand All @@ -374,11 +385,11 @@ public function provideWhereNumericCompareCases(): iterable
yield [['2 + 2'], '=', ['[]', [4]]];
yield [['2 + 2'], '=', ['[] + []', [1, 3]]];
yield [['[] + []', [-1, 5]], '=', ['[] + []', [1, 3]]];
yield [['2 + 2'], '=', ['[]', ['4']], true, false, true];
yield [['2 + 2'], '=', ['[]', ['4']], true];
yield [['2 + 2.5'], '=', ['[]', [4.5]]];
yield [['2 + 2.5'], '=', ['[] + []', [1.5, 3.0]]];
yield [['[] + []', [-1.5, 6.0]], '=', ['[] + []', [1.5, 3.0]]];
yield [['2 + 2.5'], '=', ['[]', ['4.5']], true, false, true];
yield [['2 + 2.5'], '=', ['[]', ['4.5']], true];
}

public function testGroupConcat(): void
Expand Down
6 changes: 6 additions & 0 deletions tests/ScopeTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -333,6 +333,12 @@ public function testConditionOnReferencedRecords(): void
$user->addCondition('Tickets/user/country_id/Users/country_id/Users/name', '!=', null); // should be always true
}

// remove once SQLite affinity of expressions is fixed natively
// needed for \Atk4\Data\Persistence\Sql\Sqlite\Query::_renderConditionBinary() fix
if ($this->getDatabasePlatform() instanceof SQLitePlatform) {
return;
}

self::assertSame(2, $user->executeCountQuery());
foreach ($user as $u) {
self::assertTrue(in_array($u->get('name'), ['Aerton', 'Rubens'], true));
Expand Down