From c75d3583b0843e0d5d52bc689a473a448df44750 Mon Sep 17 00:00:00 2001 From: Oscar Reimer Date: Thu, 28 Nov 2024 15:16:05 +0100 Subject: [PATCH] Add support for Postgres positional parameters to Parser --- src/Driver/PgSQL/ConvertParameters.php | 10 +++ src/SQL/Parser.php | 4 +- ...PostgresNativePositionalParametersTest.php | 42 +++++++++ tests/SQL/ParserTest.php | 85 +++++++++++++++++++ 4 files changed, 139 insertions(+), 2 deletions(-) create mode 100644 tests/Functional/SQL/PostgresNativePositionalParametersTest.php diff --git a/src/Driver/PgSQL/ConvertParameters.php b/src/Driver/PgSQL/ConvertParameters.php index 795f12d2fa4..0e137b6d3c5 100644 --- a/src/Driver/PgSQL/ConvertParameters.php +++ b/src/Driver/PgSQL/ConvertParameters.php @@ -8,6 +8,8 @@ use function count; use function implode; +use function ltrim; +use function str_starts_with; final class ConvertParameters implements Visitor { @@ -19,6 +21,14 @@ final class ConvertParameters implements Visitor public function acceptPositionalParameter(string $sql): void { + if (str_starts_with($sql, '$')) { + $position = (int) ltrim($sql, '$'); + $this->parameterMap[$position] = $position; + $this->buffer[] = $sql; + + return; + } + $position = count($this->parameterMap) + 1; $this->parameterMap[$position] = $position; $this->buffer[] = '$' . $position; diff --git a/src/SQL/Parser.php b/src/SQL/Parser.php index ad30f099079..e4964484028 100644 --- a/src/SQL/Parser.php +++ b/src/SQL/Parser.php @@ -34,13 +34,13 @@ */ final class Parser { - private const SPECIAL_CHARS = ':\?\'"`\\[\\-\\/'; + private const SPECIAL_CHARS = ':\?\'"`\\[\\-\\/$'; private const BACKTICK_IDENTIFIER = '`[^`]*`'; private const BRACKET_IDENTIFIER = '(?addColumn('a_number', Types::SMALLINT); + $table->addColumn('a_number_2', Types::SMALLINT); + $table->addColumn('b_number', Types::SMALLINT); + $table->addColumn('c_number', Types::SMALLINT); + $table->addColumn('a_number_3', Types::SMALLINT); + $this->dropAndCreateTable($table); + $this->connection->executeStatement( + 'INSERT INTO dummy_table (a_number, a_number_2, b_number, c_number, a_number_3)' . + ' VALUES ($1, $1, $2, $3, $1)', + [1, 2, 3], + [ParameterType::INTEGER, ParameterType::INTEGER, ParameterType::INTEGER], + ); + $result = $this->connection->executeQuery('SELECT * FROM dummy_table')->fetchAllAssociative(); + self::assertCount(1, $result); + self::assertEquals(1, $result[0]['a_number']); + self::assertEquals(1, $result[0]['a_number_2']); + self::assertEquals(2, $result[0]['b_number']); + self::assertEquals(3, $result[0]['c_number']); + self::assertEquals(1, $result[0]['a_number_3']); + } +} diff --git a/tests/SQL/ParserTest.php b/tests/SQL/ParserTest.php index e861dfeb74a..491338bc38a 100644 --- a/tests/SQL/ParserTest.php +++ b/tests/SQL/ParserTest.php @@ -45,61 +45,121 @@ private static function getStatementsWithParameters(): iterable 'SELECT {?}', ]; + yield [ + 'SELECT $1', + 'SELECT {$1}', + ]; + yield [ 'SELECT * FROM Foo WHERE bar IN (?, ?, ?)', 'SELECT * FROM Foo WHERE bar IN ({?}, {?}, {?})', ]; + yield [ + 'SELECT * FROM Foo WHERE bar IN ($1, $2, $1)', + 'SELECT * FROM Foo WHERE bar IN ({$1}, {$2}, {$1})', + ]; + yield [ 'SELECT ? FROM ?', 'SELECT {?} FROM {?}', ]; + yield [ + 'SELECT $1 FROM $2', + 'SELECT {$1} FROM {$2}', + ]; + yield [ 'SELECT "?" FROM foo WHERE bar = ?', 'SELECT "?" FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT "$1" FROM foo WHERE bar = $1', + 'SELECT "$1" FROM foo WHERE bar = {$1}', + ]; + yield [ "SELECT '?' FROM foo WHERE bar = ?", "SELECT '?' FROM foo WHERE bar = {?}", ]; + yield [ + "SELECT '$1' FROM foo WHERE bar = $1", + "SELECT '$1' FROM foo WHERE bar = {\$1}", + ]; + yield [ 'SELECT `?` FROM foo WHERE bar = ?', 'SELECT `?` FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT `$1` FROM foo WHERE bar = $1', + 'SELECT `$1` FROM foo WHERE bar = {$1}', + ]; + yield [ 'SELECT [?] FROM foo WHERE bar = ?', 'SELECT [?] FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT [$1] FROM foo WHERE bar = $1', + 'SELECT [$1] FROM foo WHERE bar = {$1}', + ]; + yield [ 'SELECT * FROM foo WHERE jsonb_exists_any(foo.bar, ARRAY[?])', 'SELECT * FROM foo WHERE jsonb_exists_any(foo.bar, ARRAY[{?}])', ]; + yield [ + 'SELECT * FROM foo WHERE jsonb_exists_any(foo.bar, ARRAY[$1])', + 'SELECT * FROM foo WHERE jsonb_exists_any(foo.bar, ARRAY[{$1}])', + ]; + yield [ "SELECT 'Doctrine\DBAL?' FROM foo WHERE bar = ?", "SELECT 'Doctrine\DBAL?' FROM foo WHERE bar = {?}", ]; + yield [ + "SELECT 'Doctrine\DBAL$1' FROM foo WHERE bar = $1", + "SELECT 'Doctrine\DBAL$1' FROM foo WHERE bar = {\$1}", + ]; + yield [ 'SELECT "Doctrine\DBAL?" FROM foo WHERE bar = ?', 'SELECT "Doctrine\DBAL?" FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT "Doctrine\DBAL$1" FROM foo WHERE bar = $1', + 'SELECT "Doctrine\DBAL$1" FROM foo WHERE bar = {$1}', + ]; + yield [ 'SELECT `Doctrine\DBAL?` FROM foo WHERE bar = ?', 'SELECT `Doctrine\DBAL?` FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT `Doctrine\DBAL$1` FROM foo WHERE bar = $1', + 'SELECT `Doctrine\DBAL$1` FROM foo WHERE bar = {$1}', + ]; + yield [ 'SELECT [Doctrine\DBAL?] FROM foo WHERE bar = ?', 'SELECT [Doctrine\DBAL?] FROM foo WHERE bar = {?}', ]; + yield [ + 'SELECT [Doctrine\DBAL?] FROM foo WHERE bar = $1', + 'SELECT [Doctrine\DBAL?] FROM foo WHERE bar = {$1}', + ]; + yield [ 'SELECT :foo FROM :bar', 'SELECT {:foo} FROM {:bar}', @@ -293,6 +353,31 @@ private static function getStatementsWithParameters(): iterable , ]; + yield 'Postgres placeholders inside comments' => [ + <<<'SQL' +/* + * test placeholder $1 + */ +SELECT dummy as "dummy$1" + FROM DUAL + WHERE '$1' = '$1' +-- AND dummy <> $1 + AND dummy = $1 +SQL +, + <<<'SQL' +/* + * test placeholder $1 + */ +SELECT dummy as "dummy$1" + FROM DUAL + WHERE '$1' = '$1' +-- AND dummy <> $1 + AND dummy = {$1} +SQL +, + ]; + yield 'Escaped question' => [ <<<'SQL' SELECT '{"a":null}'::jsonb ?? :key