From 517c85992578bbf5b1866f5da89836cb36d47f50 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Sat, 14 Jun 2025 14:53:15 +1000 Subject: [PATCH 1/4] Added upsert functionality for MySQL, Postgres and SQLite --- src/Database.php | 8 + src/DatabaseInterface.php | 10 ++ src/Driver/Compiler.php | 48 ++++++ src/Driver/CompilerInterface.php | 1 + src/Driver/MySQL/MySQLDriver.php | 2 + src/Driver/Postgres/PostgresCompiler.php | 42 +++++ src/Driver/Postgres/PostgresDriver.php | 2 + .../Postgres/Query/PostgresUpsertQuery.php | 106 ++++++++++++ .../SQLServer/Query/SQLServerUpsertQuery.php | 84 ++++++++++ src/Driver/SQLServer/SQLServerCompiler.php | 6 + src/Driver/SQLServer/SQLServerDriver.php | 2 + src/Driver/SQLite/SQLiteCompiler.php | 26 +++ src/Driver/SQLite/SQLiteDriver.php | 2 + src/Query/BuilderInterface.php | 9 + src/Query/QueryBuilder.php | 18 ++ src/Query/UpsertQuery.php | 155 ++++++++++++++++++ src/Table.php | 45 +++++ 17 files changed, 566 insertions(+) create mode 100644 src/Driver/Postgres/Query/PostgresUpsertQuery.php create mode 100644 src/Driver/SQLServer/Query/SQLServerUpsertQuery.php create mode 100644 src/Query/UpsertQuery.php diff --git a/src/Database.php b/src/Database.php index cb7ec1be..15210ab7 100644 --- a/src/Database.php +++ b/src/Database.php @@ -17,6 +17,7 @@ use Cycle\Database\Query\InsertQuery; use Cycle\Database\Query\SelectQuery; use Cycle\Database\Query\UpdateQuery; +use Cycle\Database\Query\UpsertQuery; /** * Database class is high level abstraction at top of Driver. Databases usually linked to real @@ -139,6 +140,13 @@ public function insert(?string $table = null): InsertQuery ->insertQuery($this->prefix, $table); } + public function upsert(?string $table = null): UpsertQuery + { + return $this->getDriver(self::WRITE) + ->getQueryBuilder() + ->upsertQuery($this->prefix, $table); + } + public function update(?string $table = null, array $values = [], array $where = []): UpdateQuery { return $this->getDriver(self::WRITE) diff --git a/src/DatabaseInterface.php b/src/DatabaseInterface.php index 421826a7..bf947902 100644 --- a/src/DatabaseInterface.php +++ b/src/DatabaseInterface.php @@ -17,6 +17,7 @@ use Cycle\Database\Query\InsertQuery; use Cycle\Database\Query\SelectQuery; use Cycle\Database\Query\UpdateQuery; +use Cycle\Database\Query\UpsertQuery; /** * DatabaseInterface is high level abstraction used to represent single database. You must always @@ -104,6 +105,15 @@ public function query(string $query, array $parameters = []): StatementInterface */ public function insert(string $table = ''): InsertQuery; + /** + * Get instance of UpsertBuilder associated with current Database. + * + * @param string $table Table where values should be upserted to. + * + * @see self::withoutCache() May be useful to disable query cache for batch inserts. + */ + public function upsert(string $table = ''): UpsertQuery; + /** * Get instance of UpdateBuilder associated with current Database. * diff --git a/src/Driver/Compiler.php b/src/Driver/Compiler.php index 2a664ec5..3455845c 100644 --- a/src/Driver/Compiler.php +++ b/src/Driver/Compiler.php @@ -109,6 +109,9 @@ protected function fragment( case self::INSERT_QUERY: return $this->insertQuery($params, $q, $tokens); + case self::UPSERT_QUERY: + return $this->upsertQuery($params, $q, $tokens); + case self::SELECT_QUERY: if ($nestedQuery) { if ($fragment->getPrefix() !== null) { @@ -166,6 +169,51 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens ); } + /** + * @psalm-return non-empty-string + */ + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + if (\count($tokens['columns']) === 0) { + throw new CompilerException('Upsert query must define at least one column'); + } + + $values = []; + foreach ($tokens['values'] as $value) { + $values[] = $this->value($params, $q, $value); + } + + $alias = $tokens['alias'] ?? \uniqid(); + + return \sprintf( + 'INSERT INTO %s (%s) VALUES %s AS %s ON DUPLICATE KEY UPDATE %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + $this->name($params, $q, $alias), + $this->updates($params, $q, $tokens['columns'], $alias), + ); + } + + protected function updates( + QueryParameters $params, + Quoter $q, + array $columns, + ?string $alias = null, + int $maxLength = 180, + ): string { + $columns = \array_map( + function ($column) use ($params, $q, $alias) { + $name = $this->name($params, $q, $column); + $alias = $this->name($params, $q, $alias); + return \sprintf('%s = %s.%s', $name, $alias, $name); + }, + $columns, + ); + + return \wordwrap(\implode(', ', $columns), $maxLength); + } + /** * @psalm-return non-empty-string */ diff --git a/src/Driver/CompilerInterface.php b/src/Driver/CompilerInterface.php index c227f523..dad4e4d6 100644 --- a/src/Driver/CompilerInterface.php +++ b/src/Driver/CompilerInterface.php @@ -24,6 +24,7 @@ interface CompilerInterface public const UPDATE_QUERY = 6; public const DELETE_QUERY = 7; public const JSON_EXPRESSION = 8; + public const UPSERT_QUERY = 9; public const TOKEN_AND = '@AND'; public const TOKEN_OR = '@OR'; public const TOKEN_AND_NOT = '@AND NOT'; diff --git a/src/Driver/MySQL/MySQLDriver.php b/src/Driver/MySQL/MySQLDriver.php index 01d02eb1..b2c83574 100644 --- a/src/Driver/MySQL/MySQLDriver.php +++ b/src/Driver/MySQL/MySQLDriver.php @@ -20,6 +20,7 @@ use Cycle\Database\Exception\StatementException; use Cycle\Database\Query\InsertQuery; use Cycle\Database\Query\QueryBuilder; +use Cycle\Database\Query\UpsertQuery; /** * Talks to mysql databases. @@ -38,6 +39,7 @@ public static function create(DriverConfig $config): static new QueryBuilder( new MySQLSelectQuery(), new InsertQuery(), + new UpsertQuery(), new MySQLUpdateQuery(), new MySQLDeleteQuery(), ), diff --git a/src/Driver/Postgres/PostgresCompiler.php b/src/Driver/Postgres/PostgresCompiler.php index bbebbaac..6a4de8b2 100644 --- a/src/Driver/Postgres/PostgresCompiler.php +++ b/src/Driver/Postgres/PostgresCompiler.php @@ -15,6 +15,7 @@ use Cycle\Database\Driver\Compiler; use Cycle\Database\Driver\Postgres\Injection\CompileJson; use Cycle\Database\Driver\Quoter; +use Cycle\Database\Exception\CompilerException; use Cycle\Database\Injection\FragmentInterface; use Cycle\Database\Injection\Parameter; use Cycle\Database\Query\QueryParameters; @@ -52,6 +53,47 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens ); } + /** + * @psalm-return non-empty-string + */ + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + if (\count($tokens['columns']) === 0) { + throw new CompilerException('Upsert query must define at least one column'); + } + + $values = []; + foreach ($tokens['values'] as $value) { + $values[] = $this->value($params, $q, $value); + } + + $alias = $tokens['alias'] ?? \uniqid(); + + $query = \sprintf( + 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT DO UPDATE SET %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + $this->name($params, $q, $alias), + $this->updates($params, $q, $tokens['columns'], $alias), + ); + + if (empty($tokens['return'])) { + return $query; + } + + return \sprintf( + '%s RETURNING %s', + $query, + \implode(',', \array_map( + fn(string|FragmentInterface|null $return) => $return instanceof FragmentInterface + ? $this->fragment($params, $q, $return) + : $this->quoteIdentifier($return), + $tokens['return'], + )), + ); + } + protected function distinct(QueryParameters $params, Quoter $q, string|bool|array $distinct): string { if ($distinct === false) { diff --git a/src/Driver/Postgres/PostgresDriver.php b/src/Driver/Postgres/PostgresDriver.php index 7adee3ad..c0863d51 100644 --- a/src/Driver/Postgres/PostgresDriver.php +++ b/src/Driver/Postgres/PostgresDriver.php @@ -19,6 +19,7 @@ use Cycle\Database\Driver\Postgres\Query\PostgresInsertQuery; use Cycle\Database\Driver\Postgres\Query\PostgresSelectQuery; use Cycle\Database\Driver\Postgres\Query\PostgresUpdateQuery; +use Cycle\Database\Driver\Postgres\Query\PostgresUpsertQuery; use Cycle\Database\Exception\DriverException; use Cycle\Database\Exception\StatementException; use Cycle\Database\Query\QueryBuilder; @@ -65,6 +66,7 @@ public static function create(DriverConfig $config): static new QueryBuilder( new PostgresSelectQuery(), new PostgresInsertQuery(), + new PostgresUpsertQuery(), new PostgresUpdateQuery(), new PostgresDeleteQuery(), ), diff --git a/src/Driver/Postgres/Query/PostgresUpsertQuery.php b/src/Driver/Postgres/Query/PostgresUpsertQuery.php new file mode 100644 index 00000000..ba836600 --- /dev/null +++ b/src/Driver/Postgres/Query/PostgresUpsertQuery.php @@ -0,0 +1,106 @@ + */ + protected array $returningColumns = []; + + public function withDriver(DriverInterface $driver, ?string $prefix = null): QueryInterface + { + $driver instanceof PostgresDriver or throw new BuilderException( + 'Postgres UpsertQuery can be used only with Postgres driver', + ); + + return parent::withDriver($driver, $prefix); + } + + /** + * Set returning column. If not set, the driver will detect PK automatically. + */ + public function returning(string|FragmentInterface ...$columns): self + { + $columns === [] and throw new BuilderException('RETURNING clause should contain at least 1 column.'); + + $this->returning = \count($columns) === 1 ? \reset($columns) : null; + + $this->returningColumns = \array_values($columns); + + return $this; + } + + public function run(): mixed + { + $params = new QueryParameters(); + $queryString = $this->sqlStatement($params); + + $this->driver->isReadonly() and throw ReadonlyConnectionException::onWriteStatementExecution(); + + $result = $this->driver->query($queryString, $params->getParameters()); + + try { + if ($this->returningColumns !== []) { + if (\count($this->returningColumns) === 1) { + return $result->fetchColumn(); + } + + return $result->fetch(StatementInterface::FETCH_ASSOC); + } + + // Return PK if no RETURNING clause is set + if ($this->getPrimaryKey() !== null) { + return $result->fetchColumn(); + } + + return null; + } finally { + $result->close(); + } + } + + public function getTokens(): array + { + return parent::getTokens() + [ + 'return' => $this->returningColumns !== [] ? $this->returningColumns : (array) $this->getPrimaryKey(), + ]; + } + + private function getPrimaryKey(): ?string + { + try { + return $this->driver?->getPrimaryKey($this->prefix, $this->table); + } catch (\Throwable) { + return null; + } + } +} diff --git a/src/Driver/SQLServer/Query/SQLServerUpsertQuery.php b/src/Driver/SQLServer/Query/SQLServerUpsertQuery.php new file mode 100644 index 00000000..a144cbfb --- /dev/null +++ b/src/Driver/SQLServer/Query/SQLServerUpsertQuery.php @@ -0,0 +1,84 @@ + + */ + protected array $returningColumns = []; + + public function withDriver(DriverInterface $driver, ?string $prefix = null): QueryInterface + { + $driver instanceof SQLServerDriver or throw new BuilderException( + 'SQLServer UpsertQuery can be used only with SQLServer driver', + ); + + return parent::withDriver($driver, $prefix); + } + + public function returning(string|FragmentInterface ...$columns): self + { + $columns === [] and throw new BuilderException('RETURNING clause should contain at least 1 column.'); + + $this->returningColumns = \array_values($columns); + + return $this; + } + + public function run(): mixed + { + if ($this->returningColumns === []) { + return parent::run(); + } + + $params = new QueryParameters(); + $queryString = $this->sqlStatement($params); + + $this->driver->isReadonly() and throw ReadonlyConnectionException::onWriteStatementExecution(); + + $result = $this->driver->query($queryString, $params->getParameters()); + + try { + if (\count($this->returningColumns) === 1) { + return $result->fetchColumn(); + } + return $result->fetch(StatementInterface::FETCH_ASSOC); + } finally { + $result->close(); + } + } + + public function getTokens(): array + { + return parent::getTokens() + [ + 'return' => $this->returningColumns, + ]; + } +} diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index c7819b63..277c72d2 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -14,6 +14,7 @@ use Cycle\Database\Driver\Compiler; use Cycle\Database\Driver\Quoter; use Cycle\Database\Driver\SQLServer\Injection\CompileJson; +use Cycle\Database\Exception\CompilerException; use Cycle\Database\Injection\Fragment; use Cycle\Database\Injection\FragmentInterface; use Cycle\Database\Injection\Parameter; @@ -68,6 +69,11 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens ); } + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + throw new CompilerException('Upsert behaviour is not supported by SQLServer'); + } + /** * {@inheritDoc} * diff --git a/src/Driver/SQLServer/SQLServerDriver.php b/src/Driver/SQLServer/SQLServerDriver.php index b39cabe1..403e1fd2 100644 --- a/src/Driver/SQLServer/SQLServerDriver.php +++ b/src/Driver/SQLServer/SQLServerDriver.php @@ -19,6 +19,7 @@ use Cycle\Database\Driver\SQLServer\Query\SQLServerInsertQuery; use Cycle\Database\Driver\SQLServer\Query\SQLServerSelectQuery; use Cycle\Database\Driver\SQLServer\Query\SQLServerUpdateQuery; +use Cycle\Database\Driver\SQLServer\Query\SQLServerUpsertQuery; use Cycle\Database\Exception\DriverException; use Cycle\Database\Exception\StatementException; use Cycle\Database\Injection\ParameterInterface; @@ -45,6 +46,7 @@ public static function create(DriverConfig $config): static new QueryBuilder( new SQLServerSelectQuery(), new SQLServerInsertQuery(), + new SQLServerUpsertQuery(), new SQLServerUpdateQuery(), new SQLServerDeleteQuery(), ), diff --git a/src/Driver/SQLite/SQLiteCompiler.php b/src/Driver/SQLite/SQLiteCompiler.php index 2ecd5ecb..5f5eaa68 100644 --- a/src/Driver/SQLite/SQLiteCompiler.php +++ b/src/Driver/SQLite/SQLiteCompiler.php @@ -121,6 +121,32 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens return \implode("\n", $statement); } + /** + * @psalm-return non-empty-string + */ + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + if (\count($tokens['columns']) === 0) { + throw new CompilerException('Upsert query must define at least one column'); + } + + $values = []; + foreach ($tokens['values'] as $value) { + $values[] = $this->value($params, $q, $value); + } + + $alias = $tokens['alias'] ?? \uniqid(); + + return \sprintf( + 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT DO UPDATE SET %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + $this->name($params, $q, $alias), + $this->updates($params, $q, $tokens['columns'], $alias), + ); + } + protected function compileJsonOrderBy(string $path): FragmentInterface { return new CompileJson($path); diff --git a/src/Driver/SQLite/SQLiteDriver.php b/src/Driver/SQLite/SQLiteDriver.php index 9e40c180..261820ab 100644 --- a/src/Driver/SQLite/SQLiteDriver.php +++ b/src/Driver/SQLite/SQLiteDriver.php @@ -20,6 +20,7 @@ use Cycle\Database\Exception\StatementException; use Cycle\Database\Query\InsertQuery; use Cycle\Database\Query\QueryBuilder; +use Cycle\Database\Query\UpsertQuery; class SQLiteDriver extends Driver { @@ -35,6 +36,7 @@ public static function create(DriverConfig $config): static new QueryBuilder( new SQLiteSelectQuery(), new InsertQuery(), + new UpsertQuery(), new SQLiteUpdateQuery(), new SQLiteDeleteQuery(), ), diff --git a/src/Query/BuilderInterface.php b/src/Query/BuilderInterface.php index 7edddfb0..8040b505 100644 --- a/src/Query/BuilderInterface.php +++ b/src/Query/BuilderInterface.php @@ -33,6 +33,15 @@ public function insertQuery( ?string $table = null, ): InsertQuery; + /** + * Get UpsertQuery builder with driver specific query compiler. + * + */ + public function upsertQuery( + string $prefix, + ?string $table = null, + ): UpsertQuery; + /** * Get SelectQuery builder with driver specific query compiler. * diff --git a/src/Query/QueryBuilder.php b/src/Query/QueryBuilder.php index 3c06b8ca..f69d8fb5 100644 --- a/src/Query/QueryBuilder.php +++ b/src/Query/QueryBuilder.php @@ -23,6 +23,7 @@ final class QueryBuilder implements BuilderInterface public function __construct( private SelectQuery $selectQuery, private InsertQuery $insertQuery, + private UpsertQuery $upsertQuery, private UpdateQuery $updateQuery, private DeleteQuery $deleteQuery, ) {} @@ -32,6 +33,7 @@ public static function defaultBuilder(): self return new self( new SelectQuery(), new InsertQuery(), + new UpsertQuery(), new UpdateQuery(), new DeleteQuery(), ); @@ -61,6 +63,22 @@ public function insertQuery( return $insert; } + /** + * Get UpsertQuery builder with driver specific query compiler. + */ + public function upsertQuery( + string $prefix, + ?string $table = null, + ): UpsertQuery { + $upsert = $this->upsertQuery->withDriver($this->driver, $prefix); + + if ($table !== null) { + $upsert->into($table); + } + + return $upsert; + } + /** * Get SelectQuery builder with driver specific query compiler. */ diff --git a/src/Query/UpsertQuery.php b/src/Query/UpsertQuery.php new file mode 100644 index 00000000..8b9292d2 --- /dev/null +++ b/src/Query/UpsertQuery.php @@ -0,0 +1,155 @@ +table = $table ?? ''; + } + + /** + * Set upsert target table. + * + * @psalm-param non-empty-string $into + */ + public function into(string $into): self + { + $this->table = $into; + + return $this; + } + + /** + * Set upsert column names. Names can be provided as array, set of parameters or comma + * separated string. + * + * Examples: + * $upsert->columns(["name", "email"]); + * $upsert->columns("name", "email"); + * $upsert->columns("name, email"); + */ + public function columns(array|string ...$columns): self + { + $this->columns = $this->fetchIdentifiers($columns); + + return $this; + } + + /** + * Set upsert rowset values or multiple rowsets. Values can be provided in multiple forms + * (method parameters, array of values, array of rowsets). Columns names will be automatically + * fetched (if not already specified) from first provided rowset based on rowset keys. + * + * Examples: + * $upsert->columns("name", "balance")->values("Wolfy-J", 10); + * $upsert->values([ + * "name" => "Wolfy-J", + * "balance" => 10 + * ]); + * $upsert->values([ + * [ + * "name" => "Wolfy-J", + * "balance" => 10 + * ], + * [ + * "name" => "Ben", + * "balance" => 20 + * ] + * ]); + */ + public function values(mixed $rowsets): self + { + if (!\is_array($rowsets)) { + return $this->values(\func_get_args()); + } + + if ($rowsets === []) { + return $this; + } + + //Checking if provided set is array of multiple + \reset($rowsets); + + if (!\is_array($rowsets[\key($rowsets)])) { + if ($this->columns === []) { + $this->columns = \array_keys($rowsets); + } + + $this->values[] = new Parameter(\array_values($rowsets)); + } else { + if ($this->columns === []) { + $this->columns = \array_keys($rowsets[\key($rowsets)]); + } + + foreach ($rowsets as $values) { + $this->values[] = new Parameter(\array_values($values)); + } + } + + return $this; + } + + /** + * Defines an alias name when performing an upsert. By default, and when specified as NULL + * a unique value will be generated and used in its place. + * + * Examples: + * $upsert->alias("foo"); + */ + public function alias(?string $alias): self + { + $this->alias = $alias; + return $this; + } + + /** + * Run the query and return last insert id. + * Returns an assoc array of values if multiple columns were specified as returning columns. + * + * @return array|int|non-empty-string|null + */ + public function run(): mixed + { + $params = new QueryParameters(); + $queryString = $this->sqlStatement($params); + + $this->driver->execute( + $queryString, + $params->getParameters(), + ); + + $lastID = $this->driver->lastInsertID(); + if (\is_numeric($lastID)) { + return (int) $lastID; + } + + return $lastID; + } + + public function getType(): int + { + return CompilerInterface::UPSERT_QUERY; + } + + public function getTokens(): array + { + return [ + 'table' => $this->table, + 'columns' => $this->columns, + 'values' => $this->values, + 'alias' => $this->alias, + ]; + } +} diff --git a/src/Table.php b/src/Table.php index ba5b3884..4153e848 100644 --- a/src/Table.php +++ b/src/Table.php @@ -16,6 +16,7 @@ use Cycle\Database\Query\InsertQuery; use Cycle\Database\Query\SelectQuery; use Cycle\Database\Query\UpdateQuery; +use Cycle\Database\Query\UpsertQuery; use Cycle\Database\Schema\AbstractTable; /** @@ -126,6 +127,41 @@ public function insertMultiple(array $columns = [], array $rowsets = []): void ->run(); } + /** + * Upsert one fieldset into table and return last inserted id. + * + * Example: + * $table->upsertOne(["name" => "Wolfy-J", "balance" => 10]); + * + * @throws BuilderException + */ + public function upsertOne(array $rowset = []): int|string|null + { + return $this->database + ->upsert($this->name) + ->values($rowset) + ->run(); + } + + /** + * Perform batch upsert into table, every rowset should have identical amount of values matched + * with column names provided in first argument. Method will return lastInsertID on success. + * + * Example: + * $table->insertMultiple(["name", "balance"], array(["Bob", 10], ["Jack", 20])) + * + * @param array $columns Array of columns. + * @param array $rowsets Array of rowsets. + */ + public function upsertMultiple(array $columns = [], array $rowsets = []): void + { + $this->database + ->upsert($this->name) + ->columns($columns) + ->values($rowsets) + ->run(); + } + /** * Get insert builder specific to current table. */ @@ -135,6 +171,15 @@ public function insert(): InsertQuery ->insert($this->name); } + /** + * Get upsert builder specific to current table. + */ + public function upsert(): UpsertQuery + { + return $this->database + ->upsert($this->name); + } + /** * Get SelectQuery builder with pre-populated from tables. */ From 2460621ba857487aca2ced9468ce473caf08562a Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Sat, 14 Jun 2025 14:53:34 +1000 Subject: [PATCH 2/4] Added upsert test cases for MySQL, Postgres and SQLite --- .../Driver/Common/Query/UpsertQueryTest.php | 313 ++++++++++++++++++ .../Driver/MySQL/Query/UpsertQueryTest.php | 17 + .../Driver/Postgres/Query/UpsertQueryTest.php | 26 ++ .../SQLServer/Query/UpsertQueryTest.php | 33 ++ .../Driver/SQLite/Query/UpsertQueryTest.php | 18 + 5 files changed, 407 insertions(+) create mode 100644 tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php create mode 100644 tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php create mode 100644 tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php create mode 100644 tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php create mode 100644 tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php diff --git a/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php new file mode 100644 index 00000000..a57f14ac --- /dev/null +++ b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php @@ -0,0 +1,313 @@ + [ + 'table' => 'table', + 'alias' => 'target', + 'values' => ['name' => 'Adam'], + 'compile' => true, + 'expected' => \sprintf('INSERT INTO {table} ({name}) VALUES (\'Adam\') AS {target} %s {name} = {target}.{name}', static::UPSERT_CLAUSE), + ], + 'upsert' => [ + 'table' => 'table', + 'alias' => 'target', + 'values' => ['name' => 'Adam'], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}) VALUES (?) AS {target} %s {name} = {target}.{name}', static::UPSERT_CLAUSE), + ], + ]; + } + + public static function queryWithStatesValuesDataProvider(): array + { + return [ + 'compile' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => ['Adam', 400], + 'compile' => true, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + 'upsert' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => ['Adam', 400], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + ]; + } + + public static function queryWithMultipleRowsDataProvider(): array + { + return [ + 'compile' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => [ + ['Adam', 400], + ['John', 200], + ], + 'compile' => true, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400), (\'John\', 200) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + 'upsert' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => [ + ['Adam', 400], + ['John', 200], + ], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?), (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + ]; + } + + public static function queryWithMultipleRowsAsArrayDataProvider(): array + { + return [ + 'compile' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => [ + ['name' => 'Adam', 'balance' => 400], + ['name' => 'John', 'balance' => 200], + ], + 'compile' => true, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400), (\'John\', 200) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + 'upsert' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'balance'], + 'values' => [ + ['name' => 'Adam', 'balance' => 400], + ['name' => 'John', 'balance' => 200], + ], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?), (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), + ], + 'expression' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'created_at', 'updated_at', 'deleted_at'], + 'values' => [ + 'name' => 'Adam', + 'created_at' => new Expression('NOW()'), + 'updated_at' => new Expression('NOW()'), + 'deleted_at' => null, + ], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, NOW(), NOW(), ?) AS {target} %s {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}', static::UPSERT_CLAUSE), + 'params' => ['Adam', null], + ], + 'fragment' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'created_at', 'updated_at', 'deleted_at'], + 'values' => [ + 'name' => 'Adam', + 'created_at' => new Fragment('NOW()'), + 'updated_at' => new Fragment('NOW()'), + 'deleted_at' => new Fragment('datetime(\'now\')'), + ], + 'compile' => false, + 'expected' => \sprintf('INSERT INTO {table} ({name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, NOW(), NOW(), datetime(\'now\')) AS {target} %s {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}', static::UPSERT_CLAUSE), + ], + ]; + } + + public static function queryWithCustomFragmentDataProvider(): array + { + return [ + 'compile' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'updated_at'], + 'values' => [ + 'name' => 'Adam', + ], + 'compile' => true, + 'expected' => \sprintf(\sprintf('INSERT INTO {table} ({name}, {updated_at}) VALUES (\'Adam\', NOW()) AS {target} %s {name} = {target}.{name}, {updated_at} = {target}.{updated_at}', static::UPSERT_CLAUSE), static::UPSERT_CLAUSE), + 'params' => ['Adam'], + ], + 'upsert' => [ + 'table' => 'table', + 'alias' => 'target', + 'columns' => ['name', 'updated_at'], + 'values' => [ + 'name' => 'Adam', + ], + 'compile' => false, + 'expected' => \sprintf(\sprintf('INSERT INTO {table} ({name}, {updated_at}) VALUES (?, NOW()) AS {target} %s {name} = {target}.{name}, {updated_at} = {target}.{updated_at}', static::UPSERT_CLAUSE), static::UPSERT_CLAUSE), + 'params' => ['Adam'], + ], + ]; + } + + public function testQueryInstance(): void + { + $this->assertInstanceOf( + UpsertQuery::class, + $this->database->upsert(), + ); + + $this->assertInstanceOf( + UpsertQuery::class, + $this->database->table->upsert(), + ); + } + + public function testNoColumnsThrowsException(): void + { + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert query must define at least one column'); + + $this->db()->upsert('table')->values([])->__toString(); + } + + /** + * @dataProvider queryWithValuesDataProvider + */ + public function testQueryWithValues( + string $table, + string $alias, + array $values, + bool $compile, + string $expected, + ): void { + $upsert = $this->db()->upsert($table)->alias($alias)->values($values); + + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + } + + /** + * @dataProvider queryWithStatesValuesDataProvider + */ + public function testQueryWithStatesValues( + string $table, + string $alias, + array $columns, + array $values, + bool $compile, + string $expected, + ): void { + $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values(...$values); + + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + } + + /** + * @dataProvider queryWithMultipleRowsDataProvider + */ + public function testQueryWithMultipleRows( + string $table, + string $alias, + array $columns, + array $values, + bool $compile, + string $expected, + ): void { + $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns); + + foreach ($values as $row) { + $upsert->values(...$row); + } + + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + } + + /** + * @dataProvider queryWithMultipleRowsAsArrayDataProvider + */ + public function testQueryWithMultipleRowsAsArray( + string $table, + string $alias, + array $columns, + array $values, + bool $compile, + string $expected, + ?array $params = null, + ): void { + $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); + + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + + if ($params !== null) { + $this->assertSameParameters($params, $upsert); + } + } + + /** + * @dataProvider queryWithCustomFragmentDataProvider + */ + public function testQueryWithCustomFragment( + string $table, + string $alias, + array $columns, + array $values, + bool $compile, + string $expected, + ?array $params = null, + ): void { + $fragment = $this->createMock(FragmentInterface::class); + $fragment->method('getType')->willReturn(CompilerInterface::FRAGMENT); + $fragment->method('getTokens')->willReturn([ + 'fragment' => 'NOW()', + 'parameters' => [], + ]); + + $values['updated_at'] = $fragment; + + $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + + if ($params !== null) { + $this->assertSameParameters($params, $upsert); + } + + // cached query + $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); + $actual = $compile ? $upsert->__toString() : $upsert; + + $this->assertSameQuery($expected, $actual); + + if ($params !== null) { + $this->assertSameParameters($params, $upsert); + } + } +} diff --git a/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php new file mode 100644 index 00000000..46921a47 --- /dev/null +++ b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php @@ -0,0 +1,17 @@ +assertInstanceOf(PostgresUpsertQuery::class, $this->database->upsert()); + } +} diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php new file mode 100644 index 00000000..868903aa --- /dev/null +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -0,0 +1,33 @@ +assertInstanceOf(SQLServerUpsertQuery::class, $this->database->upsert()); + $this->assertInstanceOf(SQLServerUpsertQuery::class, $this->database->table->upsert()); + } + + public function testCompileUpsertQueryThrowsException(): void + { + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert behaviour is not supported by SQLServer'); + + $this->db()->upsert('table')->values([])->__toString(); + } +} diff --git a/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php new file mode 100644 index 00000000..0dcf3cd4 --- /dev/null +++ b/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php @@ -0,0 +1,18 @@ + Date: Sat, 14 Jun 2025 19:05:02 +1000 Subject: [PATCH 3/4] Some assumptions were wrong, now supporting upserting for all drivers --- src/Driver/Compiler.php | 24 +- src/Driver/MySQL/MySQLCompiler.php | 26 ++ src/Driver/Postgres/PostgresCompiler.php | 21 +- src/Driver/SQLServer/SQLServerCompiler.php | 80 +++- src/Driver/SQLite/SQLiteCompiler.php | 26 -- src/Query/UpsertQuery.php | 57 ++- .../Driver/Common/Query/UpsertQueryTest.php | 379 ++++++------------ .../Driver/MySQL/Query/UpsertQueryTest.php | 7 + .../Driver/Postgres/Query/UpsertQueryTest.php | 9 +- .../SQLServer/Query/UpsertQueryTest.php | 27 +- .../Driver/SQLite/Query/UpsertQueryTest.php | 1 - 11 files changed, 301 insertions(+), 356 deletions(-) diff --git a/src/Driver/Compiler.php b/src/Driver/Compiler.php index 3455845c..8d91a7dd 100644 --- a/src/Driver/Compiler.php +++ b/src/Driver/Compiler.php @@ -174,24 +174,28 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens */ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string { + if (\count($tokens['conflicts']) === 0) { + throw new CompilerException('Upsert query must define conflicting index column names'); + } + if (\count($tokens['columns']) === 0) { throw new CompilerException('Upsert query must define at least one column'); } $values = []; + foreach ($tokens['values'] as $value) { $values[] = $this->value($params, $q, $value); } - $alias = $tokens['alias'] ?? \uniqid(); - return \sprintf( - 'INSERT INTO %s (%s) VALUES %s AS %s ON DUPLICATE KEY UPDATE %s', + 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT (%s) DO UPDATE SET %s', $this->name($params, $q, $tokens['table'], true), $this->columns($params, $q, $tokens['columns']), \implode(', ', $values), - $this->name($params, $q, $alias), - $this->updates($params, $q, $tokens['columns'], $alias), + $this->name($params, $q, $tokens['target']), + $this->columns($params, $q, $tokens['conflicts']), + $this->updates($params, $q, $tokens['columns'], $tokens['target']), ); } @@ -199,14 +203,14 @@ protected function updates( QueryParameters $params, Quoter $q, array $columns, - ?string $alias = null, + string $target, int $maxLength = 180, ): string { $columns = \array_map( - function ($column) use ($params, $q, $alias) { - $name = $this->name($params, $q, $column); - $alias = $this->name($params, $q, $alias); - return \sprintf('%s = %s.%s', $name, $alias, $name); + function ($column) use ($params, $q, $target) { + $name = $this->name($params, $q, $column); + $target = $this->name($params, $q, $target); + return \sprintf('%s = %s.%s', $name, $target, $name); }, $columns, ); diff --git a/src/Driver/MySQL/MySQLCompiler.php b/src/Driver/MySQL/MySQLCompiler.php index 4789d9f4..4c670204 100644 --- a/src/Driver/MySQL/MySQLCompiler.php +++ b/src/Driver/MySQL/MySQLCompiler.php @@ -15,6 +15,7 @@ use Cycle\Database\Driver\Compiler; use Cycle\Database\Driver\MySQL\Injection\CompileJson; use Cycle\Database\Driver\Quoter; +use Cycle\Database\Exception\CompilerException; use Cycle\Database\Injection\FragmentInterface; use Cycle\Database\Injection\Parameter; use Cycle\Database\Query\QueryParameters; @@ -36,6 +37,31 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens return parent::insertQuery($params, $q, $tokens); } + /** + * @psalm-return non-empty-string + */ + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + if (\count($tokens['columns']) === 0) { + throw new CompilerException('Upsert query must define at least one column'); + } + + $values = []; + + foreach ($tokens['values'] as $value) { + $values[] = $this->value($params, $q, $value); + } + + return \sprintf( + 'INSERT INTO %s (%s) VALUES %s AS %s ON DUPLICATE KEY UPDATE %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + $this->name($params, $q, $tokens['target']), + $this->updates($params, $q, $tokens['columns'], $tokens['target']), + ); + } + /** * * diff --git a/src/Driver/Postgres/PostgresCompiler.php b/src/Driver/Postgres/PostgresCompiler.php index 6a4de8b2..d1eb6b37 100644 --- a/src/Driver/Postgres/PostgresCompiler.php +++ b/src/Driver/Postgres/PostgresCompiler.php @@ -15,7 +15,6 @@ use Cycle\Database\Driver\Compiler; use Cycle\Database\Driver\Postgres\Injection\CompileJson; use Cycle\Database\Driver\Quoter; -use Cycle\Database\Exception\CompilerException; use Cycle\Database\Injection\FragmentInterface; use Cycle\Database\Injection\Parameter; use Cycle\Database\Query\QueryParameters; @@ -58,25 +57,7 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens */ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string { - if (\count($tokens['columns']) === 0) { - throw new CompilerException('Upsert query must define at least one column'); - } - - $values = []; - foreach ($tokens['values'] as $value) { - $values[] = $this->value($params, $q, $value); - } - - $alias = $tokens['alias'] ?? \uniqid(); - - $query = \sprintf( - 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT DO UPDATE SET %s', - $this->name($params, $q, $tokens['table'], true), - $this->columns($params, $q, $tokens['columns']), - \implode(', ', $values), - $this->name($params, $q, $alias), - $this->updates($params, $q, $tokens['columns'], $alias), - ); + $query = parent::upsertQuery($params, $q, $tokens); if (empty($tokens['return'])) { return $query; diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index 277c72d2..a137f3f0 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -69,9 +69,87 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens ); } + /** + * @psalm-return non-empty-string + */ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string { - throw new CompilerException('Upsert behaviour is not supported by SQLServer'); + if (\count($tokens['conflicts']) === 0) { + throw new CompilerException('Upsert query must define conflicting index column names'); + } + + if (\count($tokens['columns']) === 0) { + throw new CompilerException('Upsert query must define at least one column'); + } + + $values = []; + + foreach ($tokens['values'] as $value) { + $values[] = $this->value($params, $q, $value); + } + + $target = $tokens['target']; + $source = $tokens['source']; + + $conflicts = \array_map( + function ($column) use ($params, $q, $target, $source) { + $name = $this->name($params, $q, $column); + $target = $this->name($params, $q, $target); + $source = $this->name($params, $q, $source); + return \sprintf('%s.%s = %s.%s', $target, $name, $source, $name); + }, + $tokens['conflicts'], + ); + + $matched = \array_map( + function ($column) use ($params, $q, $target, $source) { + $name = $this->name($params, $q, $column); + $target = $this->name($params, $q, $target); + $source = $this->name($params, $q, $source); + return \sprintf('%s.%s = %s.%s', $target, $name, $source, $name); + }, + $tokens['columns'], + ); + + $sources = \array_map( + function ($column) use ($params, $q, $source) { + $name = $this->name($params, $q, $column); + $source = $this->name($params, $q, $source); + return \sprintf('%s.%s', $source, $name); + }, + $tokens['columns'], + ); + + //MERGE INTO users WITH (holdlock) AS target + //USING ( + // VALUES + // ('adam@email.com', 'Adam')), + // ('mark@email.com', 'Mark') + //) AS source (name, email, created_at) + //ON target.email = source.email -- assuming email has a unique constraint + //WHEN MATCHED THEN + // UPDATE SET + // target.name = source.name, + // target.email = source.email, + // target.created_at = source.created_at + //WHEN NOT MATCHED THEN + // INSERT (name, email, created_at) + // VALUES (source.name, source.email, source.created_at); + // + //MERGEINTO[table]WITH(holdlock)AS[target]USING(VALUES(?,?))AS[source]([email],[name])ON[target].[email]=[source].[email]WHENMATCHEDTHENUPDATESET[target].[email]=[source].[email],[target].[name]=[source].[name]WHENNOTMATCHEDTHENINSERT([email],[name])VALUES([source].[email],[source].[name]) + + return \sprintf( + 'MERGE INTO %s WITH (holdlock) AS %s USING ( VALUES %s) AS %s (%s) ON %s WHEN MATCHED THEN UPDATE SET %s WHEN NOT MATCHED THEN INSERT (%s) VALUES (%s)', + $this->name($params, $q, $tokens['table'], true), + $this->name($params, $q, $target), + \implode(', ', $values), + $this->name($params, $q, 'source'), + $this->columns($params, $q, $tokens['columns']), + \implode(' AND ', $conflicts), + \implode(', ', $matched), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $sources), + ); } /** diff --git a/src/Driver/SQLite/SQLiteCompiler.php b/src/Driver/SQLite/SQLiteCompiler.php index 5f5eaa68..2ecd5ecb 100644 --- a/src/Driver/SQLite/SQLiteCompiler.php +++ b/src/Driver/SQLite/SQLiteCompiler.php @@ -121,32 +121,6 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens return \implode("\n", $statement); } - /** - * @psalm-return non-empty-string - */ - protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string - { - if (\count($tokens['columns']) === 0) { - throw new CompilerException('Upsert query must define at least one column'); - } - - $values = []; - foreach ($tokens['values'] as $value) { - $values[] = $this->value($params, $q, $value); - } - - $alias = $tokens['alias'] ?? \uniqid(); - - return \sprintf( - 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT DO UPDATE SET %s', - $this->name($params, $q, $tokens['table'], true), - $this->columns($params, $q, $tokens['columns']), - \implode(', ', $values), - $this->name($params, $q, $alias), - $this->updates($params, $q, $tokens['columns'], $alias), - ); - } - protected function compileJsonOrderBy(string $path): FragmentInterface { return new CompileJson($path); diff --git a/src/Query/UpsertQuery.php b/src/Query/UpsertQuery.php index 8b9292d2..ba4ec10c 100644 --- a/src/Query/UpsertQuery.php +++ b/src/Query/UpsertQuery.php @@ -10,9 +10,11 @@ class UpsertQuery extends ActiveQuery { protected string $table; - protected array $columns = []; - protected array $values = []; - protected ?string $alias = null; + protected array $columns = []; + protected array $values = []; + protected array $conflicts = []; + protected string $target = 'target'; + protected string $source = 'source'; public function __construct(?string $table = null) { @@ -102,15 +104,44 @@ public function values(mixed $rowsets): self } /** - * Defines an alias name when performing an upsert. By default, and when specified as NULL - * a unique value will be generated and used in its place. + * Set upsert conflicting index column names. Names can be provided as array, set of parameters or comma + * separated string. + * + * Examples: + * $upsert->conflicts(["identifier", "email"]); + * $upsert->conflicts("identifier", "email"); + * $upsert->conflicts("identifier, email"); + */ + public function conflicts(array|string ...$conflicts): self + { + $this->conflicts = $this->fetchIdentifiers($conflicts); + + return $this; + } + + /** + * Set a target name when performing an upsert. * * Examples: - * $upsert->alias("foo"); + * $upsert->target("foo"); */ - public function alias(?string $alias): self + public function target(?string $target): self { - $this->alias = $alias; + $this->target = $target; + + return $this; + } + + /** + * Set a source name when performing an upsert. + * + * Examples: + * $upsert->source("bar"); + */ + public function source(?string $target): self + { + $this->target = $target; + return $this; } @@ -146,10 +177,12 @@ public function getType(): int public function getTokens(): array { return [ - 'table' => $this->table, - 'columns' => $this->columns, - 'values' => $this->values, - 'alias' => $this->alias, + 'table' => $this->table, + 'columns' => $this->columns, + 'values' => $this->values, + 'conflicts' => $this->conflicts, + 'target' => $this->target, + 'source' => $this->source, ]; } } diff --git a/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php index a57f14ac..303b6368 100644 --- a/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php @@ -14,274 +14,142 @@ abstract class UpsertQueryTest extends BaseTest { - public const UPSERT_CLAUSE = 'ON DUPLICATE KEY UPDATE'; + protected const QUERY_INSTANCE = UpsertQuery::class; + protected const QUERY_REQUIRES_CONFLICTS = true; + protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; + protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; + protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {expired_at} = {target}.{expired_at}'; - public static function queryWithValuesDataProvider(): array + public function testQueryInstance(): void { - return [ - 'compile' => [ - 'table' => 'table', - 'alias' => 'target', - 'values' => ['name' => 'Adam'], - 'compile' => true, - 'expected' => \sprintf('INSERT INTO {table} ({name}) VALUES (\'Adam\') AS {target} %s {name} = {target}.{name}', static::UPSERT_CLAUSE), - ], - 'upsert' => [ - 'table' => 'table', - 'alias' => 'target', - 'values' => ['name' => 'Adam'], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}) VALUES (?) AS {target} %s {name} = {target}.{name}', static::UPSERT_CLAUSE), - ], - ]; + $this->assertInstanceOf(static::QUERY_INSTANCE, $this->database->upsert()); + $this->assertInstanceOf(static::QUERY_INSTANCE, $this->database->table->upsert()); } - public static function queryWithStatesValuesDataProvider(): array + public function testNoConflictsThrowsException(): void { - return [ - 'compile' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => ['Adam', 400], - 'compile' => true, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - 'upsert' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => ['Adam', 400], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - ]; + if (static::QUERY_REQUIRES_CONFLICTS) { + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert query must define conflicting index column names'); + + $this->db()->upsert('table') + ->target('target') + ->values( + [ + 'email' => 'adam@email.com', + 'name' => 'Adam', + ], + )->__toString(); + } else { + $this->assertFalse(static::QUERY_REQUIRES_CONFLICTS); + } } - public static function queryWithMultipleRowsDataProvider(): array + public function testNoColumnsThrowsException(): void { - return [ - 'compile' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => [ - ['Adam', 400], - ['John', 200], - ], - 'compile' => true, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400), (\'John\', 200) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - 'upsert' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => [ - ['Adam', 400], - ['John', 200], - ], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?), (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - ]; - } + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert query must define at least one column'); - public static function queryWithMultipleRowsAsArrayDataProvider(): array - { - return [ - 'compile' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => [ - ['name' => 'Adam', 'balance' => 400], - ['name' => 'John', 'balance' => 200], - ], - 'compile' => true, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (\'Adam\', 400), (\'John\', 200) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - 'upsert' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'balance'], - 'values' => [ - ['name' => 'Adam', 'balance' => 400], - ['name' => 'John', 'balance' => 200], - ], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {balance}) VALUES (?, ?), (?, ?) AS {target} %s {name} = {target}.{name}, {balance} = {target}.{balance}', static::UPSERT_CLAUSE), - ], - 'expression' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'created_at', 'updated_at', 'deleted_at'], - 'values' => [ - 'name' => 'Adam', - 'created_at' => new Expression('NOW()'), - 'updated_at' => new Expression('NOW()'), - 'deleted_at' => null, - ], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, NOW(), NOW(), ?) AS {target} %s {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}', static::UPSERT_CLAUSE), - 'params' => ['Adam', null], - ], - 'fragment' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'created_at', 'updated_at', 'deleted_at'], - 'values' => [ - 'name' => 'Adam', - 'created_at' => new Fragment('NOW()'), - 'updated_at' => new Fragment('NOW()'), - 'deleted_at' => new Fragment('datetime(\'now\')'), - ], - 'compile' => false, - 'expected' => \sprintf('INSERT INTO {table} ({name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, NOW(), NOW(), datetime(\'now\')) AS {target} %s {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}', static::UPSERT_CLAUSE), - ], - ]; + $this->db()->upsert('table') + ->target('target') + ->conflicts('email') + ->values([])->__toString(); } - public static function queryWithCustomFragmentDataProvider(): array + public function testQueryWithValues(): void { - return [ - 'compile' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'updated_at'], - 'values' => [ - 'name' => 'Adam', - ], - 'compile' => true, - 'expected' => \sprintf(\sprintf('INSERT INTO {table} ({name}, {updated_at}) VALUES (\'Adam\', NOW()) AS {target} %s {name} = {target}.{name}, {updated_at} = {target}.{updated_at}', static::UPSERT_CLAUSE), static::UPSERT_CLAUSE), - 'params' => ['Adam'], - ], - 'upsert' => [ - 'table' => 'table', - 'alias' => 'target', - 'columns' => ['name', 'updated_at'], - 'values' => [ + $upsert = $this->db()->upsert('table') + ->target('target') + ->conflicts('email') + ->values( + [ + 'email' => 'adam@email.com', 'name' => 'Adam', ], - 'compile' => false, - 'expected' => \sprintf(\sprintf('INSERT INTO {table} ({name}, {updated_at}) VALUES (?, NOW()) AS {target} %s {name} = {target}.{name}, {updated_at} = {target}.{updated_at}', static::UPSERT_CLAUSE), static::UPSERT_CLAUSE), - 'params' => ['Adam'], - ], - ]; - } - - public function testQueryInstance(): void - { - $this->assertInstanceOf( - UpsertQuery::class, - $this->database->upsert(), - ); + ); - $this->assertInstanceOf( - UpsertQuery::class, - $this->database->table->upsert(), - ); + $this->assertSameQuery(static::QUERY_WITH_VALUES, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam'], $upsert); } - public function testNoColumnsThrowsException(): void + public function testQueryWithStatesValues(): void { - $this->expectException(CompilerException::class); - $this->expectExceptionMessage('Upsert query must define at least one column'); - - $this->db()->upsert('table')->values([])->__toString(); + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->columns('email', 'name') + ->values('adam@email.com', 'Adam'); + + $this->assertSameQuery(static::QUERY_WITH_STATES_VALUES, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam'], $upsert); } - /** - * @dataProvider queryWithValuesDataProvider - */ - public function testQueryWithValues( - string $table, - string $alias, - array $values, - bool $compile, - string $expected, - ): void { - $upsert = $this->db()->upsert($table)->alias($alias)->values($values); - - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); + public function testQueryWithMultipleRows(): void + { + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->columns('email', 'name') + ->values('adam@email.com', 'Adam') + ->values('bill@email.com', 'Bill'); + + $this->assertSameQuery(static::QUERY_WITH_MULTIPLE_ROWS, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', 'bill@email.com', 'Bill'], $upsert); } - /** - * @dataProvider queryWithStatesValuesDataProvider - */ - public function testQueryWithStatesValues( - string $table, - string $alias, - array $columns, - array $values, - bool $compile, - string $expected, - ): void { - $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values(...$values); - - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); + public function testQueryWithMultipleRowsAsArray(): void + { + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->values([ + ['email' => 'adam@email.com', 'name' => 'Adam'], + ['email' => 'bill@email.com', 'name' => 'Bill'], + ]); + + $this->assertSameQuery(static::QUERY_WITH_MULTIPLE_ROWS, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', 'bill@email.com', 'Bill'], $upsert); } - /** - * @dataProvider queryWithMultipleRowsDataProvider - */ - public function testQueryWithMultipleRows( - string $table, - string $alias, - array $columns, - array $values, - bool $compile, - string $expected, - ): void { - $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns); - - foreach ($values as $row) { - $upsert->values(...$row); - } - - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); + public function testQueryWithExpressions(): void + { + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'created_at' => new Expression('NOW()'), + 'updated_at' => new Expression('NOW()'), + 'deleted_at' => null, + ]); + + $this->assertSameQuery(static::QUERY_WITH_EXPRESSIONS, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', null], $upsert); } - /** - * @dataProvider queryWithMultipleRowsAsArrayDataProvider - */ - public function testQueryWithMultipleRowsAsArray( - string $table, - string $alias, - array $columns, - array $values, - bool $compile, - string $expected, - ?array $params = null, - ): void { - $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); - - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); - - if ($params !== null) { - $this->assertSameParameters($params, $upsert); - } + public function testQueryWithFragments(): void + { + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'created_at' => new Fragment('NOW()'), + 'updated_at' => new Fragment('datetime(\'now\')'), + 'deleted_at' => null, + ]); + + $this->assertSameQuery(static::QUERY_WITH_FRAGMENTS, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', null], $upsert); } - /** - * @dataProvider queryWithCustomFragmentDataProvider - */ - public function testQueryWithCustomFragment( - string $table, - string $alias, - array $columns, - array $values, - bool $compile, - string $expected, - ?array $params = null, - ): void { + public function testQueryWithCustomFragment(): void + { $fragment = $this->createMock(FragmentInterface::class); $fragment->method('getType')->willReturn(CompilerInterface::FRAGMENT); $fragment->method('getTokens')->willReturn([ @@ -289,25 +157,16 @@ public function testQueryWithCustomFragment( 'parameters' => [], ]); - $values['updated_at'] = $fragment; - - $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); - - if ($params !== null) { - $this->assertSameParameters($params, $upsert); - } - - // cached query - $upsert = $this->database->upsert()->into($table)->alias($alias)->columns(...$columns)->values($values); - $actual = $compile ? $upsert->__toString() : $upsert; - - $this->assertSameQuery($expected, $actual); - - if ($params !== null) { - $this->assertSameParameters($params, $upsert); - } + $upsert = $this->database->upsert('table') + ->target('target') + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'expired_at' => $fragment, + ]); + + $this->assertSameQuery(static::QUERY_WITH_CUSTOM_FRAGMENT, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam'], $upsert); } } diff --git a/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php index 46921a47..499ac247 100644 --- a/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php @@ -14,4 +14,11 @@ class UpsertQueryTest extends CommonClass { public const DRIVER = 'mysql'; + protected const QUERY_REQUIRES_CONFLICTS = false; + protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; + protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; + protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; + protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {expired_at} = {target}.{expired_at}'; } diff --git a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php index 10ac629a..6878413f 100644 --- a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php @@ -15,12 +15,5 @@ class UpsertQueryTest extends CommonClass { public const DRIVER = 'postgres'; - public const UPSERT_CLAUSE = 'ON CONFLICT DO UPDATE SET'; - - public function testQueryInstance(): void - { - parent::testQueryInstance(); - - $this->assertInstanceOf(PostgresUpsertQuery::class, $this->database->upsert()); - } + protected const QUERY_INSTANCE = PostgresUpsertQuery::class; } diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index 868903aa..3199f77e 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -5,29 +5,20 @@ namespace Cycle\Database\Tests\Functional\Driver\SQLServer\Query; // phpcs:ignore -use Cycle\Database\Driver\SQLServer\Query\SQLServerUpsertQuery; -use Cycle\Database\Exception\CompilerException; -use Cycle\Database\Tests\Functional\Driver\Common\BaseTest; +use Cycle\Database\Tests\Functional\Driver\Common\Query\UpsertQueryTest as CommonClass; /** * @group driver * @group driver-sqlserver */ -final class UpsertQueryTest extends BaseTest +final class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlserver'; - - public function testQueryInstance(): void - { - $this->assertInstanceOf(SQLServerUpsertQuery::class, $this->database->upsert()); - $this->assertInstanceOf(SQLServerUpsertQuery::class, $this->database->table->upsert()); - } - - public function testCompileUpsertQueryThrowsException(): void - { - $this->expectException(CompilerException::class); - $this->expectExceptionMessage('Upsert behaviour is not supported by SQLServer'); - - $this->db()->upsert('table')->values([])->__toString(); - } + protected const QUERY_REQUIRES_CONFLICTS = false; + protected const QUERY_WITH_VALUES = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?) ) AS [source] ([email], [name]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name] WHEN NOT MATCHED THEN INSERT ([email], [name]) VALUES ([source].[email], [source].[name])'; + protected const QUERY_WITH_STATES_VALUES = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?) ) AS [source] ([email], [name]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name] WHEN NOT MATCHED THEN INSERT ([email], [name]) VALUES ([source].[email], [source].[name])'; + protected const QUERY_WITH_MULTIPLE_ROWS = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?), (?, ?) ) AS [source] ([email], [name]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name] WHEN NOT MATCHED THEN INSERT ([email], [name]) VALUES ([source].[email], [source].[name])'; + protected const QUERY_WITH_EXPRESSIONS = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, NOW(), NOW(), ?) ) AS [source] ([email], [name], [created_at], [updated_at], [deleted_at]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name], [target].[created_at] = [source].[created_at], [target].[updated_at] = [source].[updated_at], [target].[deleted_at] = [source].[deleted_at] WHEN NOT MATCHED THEN INSERT ([email], [name], [created_at], [updated_at], [deleted_at]) VALUES ([source].[email], [source].[name], [source].[created_at], [source].[updated_at], [source].[deleted_at])'; + protected const QUERY_WITH_FRAGMENTS = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, NOW(), datetime(\'now\'), ?) ) AS [source] ([email], [name], [created_at], [updated_at], [deleted_at]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name], [target].[created_at] = [source].[created_at], [target].[updated_at] = [source].[updated_at], [target].[deleted_at] = [source].[deleted_at] WHEN NOT MATCHED THEN INSERT ([email], [name], [created_at], [updated_at], [deleted_at]) VALUES ([source].[email], [source].[name], [source].[created_at], [source].[updated_at], [source].[deleted_at])'; + protected const QUERY_WITH_CUSTOM_FRAGMENT = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, NOW()) ) AS [source] ([email], [name], [expired_at]) ON [target].[email] = [source].[email] WHEN MATCHED THEN UPDATE SET [target].[email] = [source].[email], [target].[name] = [source].[name], [target].[expired_at] = [source].[expired_at] WHEN NOT MATCHED THEN INSERT ([email], [name], [expired_at]) VALUES ([source].[email], [source].[name], [source].[expired_at])'; } diff --git a/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php index 0dcf3cd4..b33597d7 100644 --- a/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php @@ -14,5 +14,4 @@ class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlite'; - public const UPSERT_CLAUSE = 'ON CONFLICT DO UPDATE SET'; } From 566134fbaf0e58f00d5927ad95da9f8d99543013 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Sat, 14 Jun 2025 20:41:46 +1000 Subject: [PATCH 4/4] Some assumptions were wrong, syntax should be correct across various drivers --- src/Driver/Compiler.php | 32 ++++++----------- src/Driver/MySQL/MySQLCompiler.php | 13 +++++-- src/Driver/SQLServer/SQLServerCompiler.php | 36 +++++-------------- src/Query/UpsertQuery.php | 30 ---------------- .../Driver/Common/Query/UpsertQueryTest.php | 21 ++++------- .../Driver/MySQL/Query/UpsertQueryTest.php | 12 +++---- 6 files changed, 41 insertions(+), 103 deletions(-) diff --git a/src/Driver/Compiler.php b/src/Driver/Compiler.php index 8d91a7dd..3b878229 100644 --- a/src/Driver/Compiler.php +++ b/src/Driver/Compiler.php @@ -188,34 +188,22 @@ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens $values[] = $this->value($params, $q, $value); } + $updates = \array_map( + function (string $column) use ($params, $q) { + $name = $this->name($params, $q, $column); + return \sprintf('%s = EXCLUDED.%s', $name, $name); + }, + $tokens['columns'], + ); + return \sprintf( - 'INSERT INTO %s (%s) VALUES %s AS %s ON CONFLICT (%s) DO UPDATE SET %s', + 'INSERT INTO %s (%s) VALUES %s ON CONFLICT (%s) DO UPDATE SET %s', $this->name($params, $q, $tokens['table'], true), $this->columns($params, $q, $tokens['columns']), \implode(', ', $values), - $this->name($params, $q, $tokens['target']), $this->columns($params, $q, $tokens['conflicts']), - $this->updates($params, $q, $tokens['columns'], $tokens['target']), - ); - } - - protected function updates( - QueryParameters $params, - Quoter $q, - array $columns, - string $target, - int $maxLength = 180, - ): string { - $columns = \array_map( - function ($column) use ($params, $q, $target) { - $name = $this->name($params, $q, $column); - $target = $this->name($params, $q, $target); - return \sprintf('%s = %s.%s', $name, $target, $name); - }, - $columns, + \implode(', ', $updates), ); - - return \wordwrap(\implode(', ', $columns), $maxLength); } /** diff --git a/src/Driver/MySQL/MySQLCompiler.php b/src/Driver/MySQL/MySQLCompiler.php index 4c670204..1106e438 100644 --- a/src/Driver/MySQL/MySQLCompiler.php +++ b/src/Driver/MySQL/MySQLCompiler.php @@ -52,13 +52,20 @@ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens $values[] = $this->value($params, $q, $value); } + $updates = \array_map( + function ($column) use ($params, $q) { + $name = $this->name($params, $q, $column); + return \sprintf('%s = VALUES(%s)', $name, $name); + }, + $tokens['columns'], + ); + return \sprintf( - 'INSERT INTO %s (%s) VALUES %s AS %s ON DUPLICATE KEY UPDATE %s', + 'INSERT INTO %s (%s) VALUES %s ON DUPLICATE KEY UPDATE %s', $this->name($params, $q, $tokens['table'], true), $this->columns($params, $q, $tokens['columns']), \implode(', ', $values), - $this->name($params, $q, $tokens['target']), - $this->updates($params, $q, $tokens['columns'], $tokens['target']), + \implode(', ', $updates), ); } diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index a137f3f0..1dcbbab5 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -88,11 +88,11 @@ protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens $values[] = $this->value($params, $q, $value); } - $target = $tokens['target']; - $source = $tokens['source']; + $target = 'target'; + $source = 'source'; $conflicts = \array_map( - function ($column) use ($params, $q, $target, $source) { + function (string $column) use ($params, $q, $target, $source) { $name = $this->name($params, $q, $column); $target = $this->name($params, $q, $target); $source = $this->name($params, $q, $source); @@ -101,8 +101,8 @@ function ($column) use ($params, $q, $target, $source) { $tokens['conflicts'], ); - $matched = \array_map( - function ($column) use ($params, $q, $target, $source) { + $updates = \array_map( + function (string $column) use ($params, $q, $target, $source) { $name = $this->name($params, $q, $column); $target = $this->name($params, $q, $target); $source = $this->name($params, $q, $source); @@ -111,8 +111,8 @@ function ($column) use ($params, $q, $target, $source) { $tokens['columns'], ); - $sources = \array_map( - function ($column) use ($params, $q, $source) { + $inserts = \array_map( + function (string $column) use ($params, $q, $source) { $name = $this->name($params, $q, $column); $source = $this->name($params, $q, $source); return \sprintf('%s.%s', $source, $name); @@ -120,24 +120,6 @@ function ($column) use ($params, $q, $source) { $tokens['columns'], ); - //MERGE INTO users WITH (holdlock) AS target - //USING ( - // VALUES - // ('adam@email.com', 'Adam')), - // ('mark@email.com', 'Mark') - //) AS source (name, email, created_at) - //ON target.email = source.email -- assuming email has a unique constraint - //WHEN MATCHED THEN - // UPDATE SET - // target.name = source.name, - // target.email = source.email, - // target.created_at = source.created_at - //WHEN NOT MATCHED THEN - // INSERT (name, email, created_at) - // VALUES (source.name, source.email, source.created_at); - // - //MERGEINTO[table]WITH(holdlock)AS[target]USING(VALUES(?,?))AS[source]([email],[name])ON[target].[email]=[source].[email]WHENMATCHEDTHENUPDATESET[target].[email]=[source].[email],[target].[name]=[source].[name]WHENNOTMATCHEDTHENINSERT([email],[name])VALUES([source].[email],[source].[name]) - return \sprintf( 'MERGE INTO %s WITH (holdlock) AS %s USING ( VALUES %s) AS %s (%s) ON %s WHEN MATCHED THEN UPDATE SET %s WHEN NOT MATCHED THEN INSERT (%s) VALUES (%s)', $this->name($params, $q, $tokens['table'], true), @@ -146,9 +128,9 @@ function ($column) use ($params, $q, $source) { $this->name($params, $q, 'source'), $this->columns($params, $q, $tokens['columns']), \implode(' AND ', $conflicts), - \implode(', ', $matched), + \implode(', ', $updates), $this->columns($params, $q, $tokens['columns']), - \implode(', ', $sources), + \implode(', ', $inserts), ); } diff --git a/src/Query/UpsertQuery.php b/src/Query/UpsertQuery.php index ba4ec10c..2c61de43 100644 --- a/src/Query/UpsertQuery.php +++ b/src/Query/UpsertQuery.php @@ -13,8 +13,6 @@ class UpsertQuery extends ActiveQuery protected array $columns = []; protected array $values = []; protected array $conflicts = []; - protected string $target = 'target'; - protected string $source = 'source'; public function __construct(?string $table = null) { @@ -119,32 +117,6 @@ public function conflicts(array|string ...$conflicts): self return $this; } - /** - * Set a target name when performing an upsert. - * - * Examples: - * $upsert->target("foo"); - */ - public function target(?string $target): self - { - $this->target = $target; - - return $this; - } - - /** - * Set a source name when performing an upsert. - * - * Examples: - * $upsert->source("bar"); - */ - public function source(?string $target): self - { - $this->target = $target; - - return $this; - } - /** * Run the query and return last insert id. * Returns an assoc array of values if multiple columns were specified as returning columns. @@ -181,8 +153,6 @@ public function getTokens(): array 'columns' => $this->columns, 'values' => $this->values, 'conflicts' => $this->conflicts, - 'target' => $this->target, - 'source' => $this->source, ]; } } diff --git a/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php index 303b6368..7ac4a286 100644 --- a/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php @@ -16,12 +16,12 @@ abstract class UpsertQueryTest extends BaseTest { protected const QUERY_INSTANCE = UpsertQuery::class; protected const QUERY_REQUIRES_CONFLICTS = true; - protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; - protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; - protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) AS {target} ON CONFLICT ({email}) DO UPDATE SET {email} = {target}.{email}, {name} = {target}.{name}, {expired_at} = {target}.{expired_at}'; + protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}'; + protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}'; + protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}'; + protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {created_at} = EXCLUDED.{created_at}, {updated_at} = EXCLUDED.{updated_at}, {deleted_at} = EXCLUDED.{deleted_at}'; + protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {created_at} = EXCLUDED.{created_at}, {updated_at} = EXCLUDED.{updated_at}, {deleted_at} = EXCLUDED.{deleted_at}'; + protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {expired_at} = EXCLUDED.{expired_at}'; public function testQueryInstance(): void { @@ -36,7 +36,6 @@ public function testNoConflictsThrowsException(): void $this->expectExceptionMessage('Upsert query must define conflicting index column names'); $this->db()->upsert('table') - ->target('target') ->values( [ 'email' => 'adam@email.com', @@ -54,7 +53,6 @@ public function testNoColumnsThrowsException(): void $this->expectExceptionMessage('Upsert query must define at least one column'); $this->db()->upsert('table') - ->target('target') ->conflicts('email') ->values([])->__toString(); } @@ -62,7 +60,6 @@ public function testNoColumnsThrowsException(): void public function testQueryWithValues(): void { $upsert = $this->db()->upsert('table') - ->target('target') ->conflicts('email') ->values( [ @@ -78,7 +75,6 @@ public function testQueryWithValues(): void public function testQueryWithStatesValues(): void { $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->columns('email', 'name') ->values('adam@email.com', 'Adam'); @@ -90,7 +86,6 @@ public function testQueryWithStatesValues(): void public function testQueryWithMultipleRows(): void { $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->columns('email', 'name') ->values('adam@email.com', 'Adam') @@ -103,7 +98,6 @@ public function testQueryWithMultipleRows(): void public function testQueryWithMultipleRowsAsArray(): void { $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->values([ ['email' => 'adam@email.com', 'name' => 'Adam'], @@ -117,7 +111,6 @@ public function testQueryWithMultipleRowsAsArray(): void public function testQueryWithExpressions(): void { $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->values([ 'email' => 'adam@email.com', @@ -134,7 +127,6 @@ public function testQueryWithExpressions(): void public function testQueryWithFragments(): void { $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->values([ 'email' => 'adam@email.com', @@ -158,7 +150,6 @@ public function testQueryWithCustomFragment(): void ]); $upsert = $this->database->upsert('table') - ->target('target') ->conflicts('email') ->values([ 'email' => 'adam@email.com', diff --git a/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php index 499ac247..d0a1eca5 100644 --- a/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php @@ -15,10 +15,10 @@ class UpsertQueryTest extends CommonClass { public const DRIVER = 'mysql'; protected const QUERY_REQUIRES_CONFLICTS = false; - protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}'; - protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; - protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {created_at} = {target}.{created_at}, {updated_at} = {target}.{updated_at}, {deleted_at} = {target}.{deleted_at}'; - protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) AS {target} ON DUPLICATE KEY UPDATE {email} = {target}.{email}, {name} = {target}.{name}, {expired_at} = {target}.{expired_at}'; + protected const QUERY_WITH_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name})'; + protected const QUERY_WITH_STATES_VALUES = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name})'; + protected const QUERY_WITH_MULTIPLE_ROWS = 'INSERT INTO {table} ({email}, {name}) VALUES (?, ?), (?, ?) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name})'; + protected const QUERY_WITH_EXPRESSIONS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), NOW(), ?) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name}), {created_at} = VALUES({created_at}), {updated_at} = VALUES({updated_at}), {deleted_at} = VALUES({deleted_at})'; + protected const QUERY_WITH_FRAGMENTS = 'INSERT INTO {table} ({email}, {name}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, NOW(), datetime(\'now\'), ?) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name}), {created_at} = VALUES({created_at}), {updated_at} = VALUES({updated_at}), {deleted_at} = VALUES({deleted_at})'; + protected const QUERY_WITH_CUSTOM_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {expired_at}) VALUES (?, ?, NOW()) ON DUPLICATE KEY UPDATE {email} = VALUES({email}), {name} = VALUES({name}), {expired_at} = VALUES({expired_at})'; }