From d06936659e4a7a79aa87cebb69381c8e71a224f0 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 12:24:22 +1000 Subject: [PATCH 01/13] Added upsert functionality for MySQL, Postgres, SQLite and SQLServer --- src/Database.php | 8 + src/DatabaseInterface.php | 10 ++ src/Driver/Compiler.php | 40 +++++ src/Driver/CompilerInterface.php | 1 + src/Driver/Jsoner.php | 2 +- src/Driver/MySQL/MySQLCompiler.php | 33 ++++ src/Driver/MySQL/MySQLDriver.php | 2 + src/Driver/Postgres/PostgresCompiler.php | 23 +++ src/Driver/Postgres/PostgresDriver.php | 2 + .../Postgres/Query/PostgresUpsertQuery.php | 106 ++++++++++++ .../SQLServer/Query/SQLServerUpsertQuery.php | 84 ++++++++++ src/Driver/SQLServer/SQLServerCompiler.php | 66 ++++++++ src/Driver/SQLServer/SQLServerDriver.php | 2 + src/Driver/SQLite/SQLiteDriver.php | 2 + src/Query/BuilderInterface.php | 9 + src/Query/QueryBuilder.php | 18 ++ src/Query/UpsertQuery.php | 158 ++++++++++++++++++ src/Table.php | 45 +++++ 18 files changed, 610 insertions(+), 1 deletion(-) 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 93ba54a9..3ad0a284 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) { @@ -169,6 +172,43 @@ 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['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); + } + + $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 ON CONFLICT (%s) DO UPDATE SET %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + $this->columns($params, $q, $tokens['conflicts']), + \implode(', ', $updates), + ); + } + /** * @psalm-return non-empty-string */ diff --git a/src/Driver/CompilerInterface.php b/src/Driver/CompilerInterface.php index 281c124b..fceabd0d 100644 --- a/src/Driver/CompilerInterface.php +++ b/src/Driver/CompilerInterface.php @@ -25,6 +25,7 @@ interface CompilerInterface public const DELETE_QUERY = 7; public const JSON_EXPRESSION = 8; public const SUBQUERY = 9; + public const UPSERT_QUERY = 10; public const TOKEN_AND = '@AND'; public const TOKEN_OR = '@OR'; public const TOKEN_AND_NOT = '@AND NOT'; diff --git a/src/Driver/Jsoner.php b/src/Driver/Jsoner.php index 7bc50eaa..fe08c02c 100644 --- a/src/Driver/Jsoner.php +++ b/src/Driver/Jsoner.php @@ -32,7 +32,7 @@ public static function toJson(mixed $value, bool $encode = true, bool $validate $result = (string) $value; - if ($validate && !json_validate($result)) { + if ($validate && !\json_validate($result)) { throw new BuilderException('Invalid JSON value.'); } diff --git a/src/Driver/MySQL/MySQLCompiler.php b/src/Driver/MySQL/MySQLCompiler.php index 4789d9f4..1106e438 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,38 @@ 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); + } + + $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 ON DUPLICATE KEY UPDATE %s', + $this->name($params, $q, $tokens['table'], true), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $values), + \implode(', ', $updates), + ); + } + /** * * 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..d1eb6b37 100644 --- a/src/Driver/Postgres/PostgresCompiler.php +++ b/src/Driver/Postgres/PostgresCompiler.php @@ -52,6 +52,29 @@ protected function insertQuery(QueryParameters $params, Quoter $q, array $tokens ); } + /** + * @psalm-return non-empty-string + */ + protected function upsertQuery(QueryParameters $params, Quoter $q, array $tokens): string + { + $query = parent::upsertQuery($params, $q, $tokens); + + 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..1dcbbab5 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,71 @@ 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['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 = 'target'; + $source = 'source'; + + $conflicts = \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); + return \sprintf('%s.%s = %s.%s', $target, $name, $source, $name); + }, + $tokens['conflicts'], + ); + + $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); + return \sprintf('%s.%s = %s.%s', $target, $name, $source, $name); + }, + $tokens['columns'], + ); + + $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); + }, + $tokens['columns'], + ); + + 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(', ', $updates), + $this->columns($params, $q, $tokens['columns']), + \implode(', ', $inserts), + ); + } + /** * {@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/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..2c61de43 --- /dev/null +++ b/src/Query/UpsertQuery.php @@ -0,0 +1,158 @@ +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; + } + + /** + * 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; + } + + /** + * 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, + 'conflicts' => $this->conflicts, + ]; + } +} 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 6007e5344e5ca164edc48c4344759f14bd09cb63 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 12:24:46 +1000 Subject: [PATCH 02/13] Added upsert test cases for MySQL, Postgres, SQLite and SQLServer --- .../Driver/Common/Query/UpsertQueryTest.php | 163 ++++++++++++++++++ .../Driver/MySQL/Query/UpsertQueryTest.php | 24 +++ .../Driver/Postgres/Query/UpsertQueryTest.php | 19 ++ .../SQLServer/Query/UpsertQueryTest.php | 24 +++ .../Driver/SQLite/Query/UpsertQueryTest.php | 17 ++ 5 files changed, 247 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..7ac4a286 --- /dev/null +++ b/tests/Database/Functional/Driver/Common/Query/UpsertQueryTest.php @@ -0,0 +1,163 @@ +assertInstanceOf(static::QUERY_INSTANCE, $this->database->upsert()); + $this->assertInstanceOf(static::QUERY_INSTANCE, $this->database->table->upsert()); + } + + public function testNoConflictsThrowsException(): void + { + if (static::QUERY_REQUIRES_CONFLICTS) { + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert query must define conflicting index column names'); + + $this->db()->upsert('table') + ->values( + [ + 'email' => 'adam@email.com', + 'name' => 'Adam', + ], + )->__toString(); + } else { + $this->assertFalse(static::QUERY_REQUIRES_CONFLICTS); + } + } + + public function testNoColumnsThrowsException(): void + { + $this->expectException(CompilerException::class); + $this->expectExceptionMessage('Upsert query must define at least one column'); + + $this->db()->upsert('table') + ->conflicts('email') + ->values([])->__toString(); + } + + public function testQueryWithValues(): void + { + $upsert = $this->db()->upsert('table') + ->conflicts('email') + ->values( + [ + 'email' => 'adam@email.com', + 'name' => 'Adam', + ], + ); + + $this->assertSameQuery(static::QUERY_WITH_VALUES, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam'], $upsert); + } + + public function testQueryWithStatesValues(): void + { + $upsert = $this->database->upsert('table') + ->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); + } + + public function testQueryWithMultipleRows(): void + { + $upsert = $this->database->upsert('table') + ->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); + } + + public function testQueryWithMultipleRowsAsArray(): void + { + $upsert = $this->database->upsert('table') + ->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); + } + + public function testQueryWithExpressions(): void + { + $upsert = $this->database->upsert('table') + ->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); + } + + public function testQueryWithFragments(): void + { + $upsert = $this->database->upsert('table') + ->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); + } + + public function testQueryWithCustomFragment(): void + { + $fragment = $this->createMock(FragmentInterface::class); + $fragment->method('getType')->willReturn(CompilerInterface::FRAGMENT); + $fragment->method('getTokens')->willReturn([ + 'fragment' => 'NOW()', + 'parameters' => [], + ]); + + $upsert = $this->database->upsert('table') + ->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 new file mode 100644 index 00000000..d0a1eca5 --- /dev/null +++ b/tests/Database/Functional/Driver/MySQL/Query/UpsertQueryTest.php @@ -0,0 +1,24 @@ + Date: Fri, 11 Jul 2025 16:02:33 +1000 Subject: [PATCH 03/13] Merge statement must be terminated by a semicolon --- src/Driver/SQLServer/SQLServerCompiler.php | 2 +- .../Driver/SQLServer/Query/UpsertQueryTest.php | 12 ++++++------ 2 files changed, 7 insertions(+), 7 deletions(-) diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index 1dcbbab5..21e6da57 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -121,7 +121,7 @@ function (string $column) use ($params, $q, $source) { ); 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)', + '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), diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index 3199f77e..ab819e3c 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -15,10 +15,10 @@ final class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlserver'; 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])'; + 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]);'; } From 2b4d72729cdcdb90a44d8452c96ac86d024bae20 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 16:10:23 +1000 Subject: [PATCH 04/13] Updated upsertOne and upsertMultiple methods to accept conflicts argument --- src/Table.php | 7 +++++-- 1 file changed, 5 insertions(+), 2 deletions(-) diff --git a/src/Table.php b/src/Table.php index 4153e848..acf494bc 100644 --- a/src/Table.php +++ b/src/Table.php @@ -132,13 +132,15 @@ public function insertMultiple(array $columns = [], array $rowsets = []): void * * Example: * $table->upsertOne(["name" => "Wolfy-J", "balance" => 10]); + * $table->upsertOne(["name" => "Wolfy-J", "balance" => 10], 'name'); * * @throws BuilderException */ - public function upsertOne(array $rowset = []): int|string|null + public function upsertOne(array $rowset = [], array|string $conflicts = []): int|string|null { return $this->database ->upsert($this->name) + ->conflicts($conflicts) ->values($rowset) ->run(); } @@ -153,10 +155,11 @@ public function upsertOne(array $rowset = []): int|string|null * @param array $columns Array of columns. * @param array $rowsets Array of rowsets. */ - public function upsertMultiple(array $columns = [], array $rowsets = []): void + public function upsertMultiple(array $columns = [], array $rowsets = [], array|string $conflicts = []): void { $this->database ->upsert($this->name) + ->conflicts($conflicts) ->columns($columns) ->values($rowsets) ->run(); From 71ef04ebb03b083453ee0d0a7460ade14bcd1ef6 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 16:11:45 +1000 Subject: [PATCH 05/13] Includes upsertOne and upsertMultiple for common table test --- .../Driver/Common/Schema/TableTest.php | 141 ++++++++++++++++++ 1 file changed, 141 insertions(+) diff --git a/tests/Database/Functional/Driver/Common/Schema/TableTest.php b/tests/Database/Functional/Driver/Common/Schema/TableTest.php index 575dbf68..ca95d3a9 100644 --- a/tests/Database/Functional/Driver/Common/Schema/TableTest.php +++ b/tests/Database/Functional/Driver/Common/Schema/TableTest.php @@ -174,6 +174,147 @@ public function testInsertOneRow(): void ); } + public function testUpsertOneRowInsert(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $insertId = $table->insertOne( + ['name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ); + + $this->assertNotNull($insertId); + $this->assertSame(1, $insertId); + $this->assertSame(1, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ], + $table->fetchAll(), + ); + + $upsertId = $table->upsertOne( + ['name' => 'Adam', 'email' => 'adam@email.com', 'balance' => 100], + 'email' + ); + + $this->assertSame(2, $upsertId); + $this->assertSame(2, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ['id' => 2, 'name' => 'Adam', 'email' => 'adam@email.com', 'balance' => 100], + ], + $table->fetchAll(), + ); + } + + public function testUpsertOneRowUpdate(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $insertId = $table->insertOne( + ['name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ); + + $this->assertNotNull($insertId); + $this->assertSame(1, $insertId); + $this->assertSame(1, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ], + $table->fetchAll(), + ); + + $upsertId = $table->upsertOne( + ['name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 50], + 'email' + ); + + $this->assertSame(1, $upsertId); + $this->assertSame(1, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 50], + ], + $table->fetchAll(), + ); + } + + public function testUpsertMultipleRows(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $insertId = $table->insertOne( + ['name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ); + + $this->assertNotNull($insertId); + $this->assertSame(1, $insertId); + $this->assertSame(1, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ], + $table->fetchAll(), + ); + + $table->upsertMultiple( + ['name', 'email', 'balance'], + [ + ['Anton', 'anton@email.com', 50], + ['Adam', 'adam@email.com', 100], + ['John', 'john@email.com', 400], + ['Mark', 'mark@email.com', 800], + ], + 'email' + ); + + $this->assertSame(4, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 50], + ['id' => 2, 'name' => 'Adam', 'email' => 'adam@email.com', 'balance' => 100], + ['id' => 3, 'name' => 'John', 'email' => 'john@email.com', 'balance' => 400], + ['id' => 4, 'name' => 'Mark', 'email' => 'mark@email.com', 'balance' => 800], + ], + $table->fetchAll(), + ); + } + /** * @requires PHP >= 8.1 */ From 802d24f82683446b3b2ca2839d3e8a5d03957b13 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 16:12:23 +1000 Subject: [PATCH 06/13] Includes overridden test case given Postgres sequence handling --- .../Driver/Postgres/Schema/TableTest.php | 53 +++++++++++++++++++ 1 file changed, 53 insertions(+) diff --git a/tests/Database/Functional/Driver/Postgres/Schema/TableTest.php b/tests/Database/Functional/Driver/Postgres/Schema/TableTest.php index 95b3900a..35a5771c 100644 --- a/tests/Database/Functional/Driver/Postgres/Schema/TableTest.php +++ b/tests/Database/Functional/Driver/Postgres/Schema/TableTest.php @@ -95,4 +95,57 @@ public function testDependencies(): void $this->assertSame(['public.table2'], $table->getDependencies()); } + + public function testUpsertMultipleRows(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $insertId = $table->insertOne( + ['name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ); + + $this->assertNotNull($insertId); + $this->assertSame(1, $insertId); + $this->assertSame(1, $table->count()); + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 10], + ], + $table->fetchAll(), + ); + + $table->upsertMultiple( + ['name', 'email', 'balance'], + [ + ['Anton', 'anton@email.com', 50], + ['Adam', 'adam@email.com', 100], + ['John', 'john@email.com', 400], + ['Mark', 'mark@email.com', 800], + ], + 'email' + ); + + $this->assertSame(4, $table->count()); + // Postgres sequences ends up N+1 when upserting + $this->assertEquals( + [ + ['id' => 1, 'name' => 'Anton', 'email' => 'anton@email.com', 'balance' => 50], + ['id' => 3, 'name' => 'Adam', 'email' => 'adam@email.com', 'balance' => 100], + ['id' => 4, 'name' => 'John', 'email' => 'john@email.com', 'balance' => 400], + ['id' => 5, 'name' => 'Mark', 'email' => 'mark@email.com', 'balance' => 800], + ], + $table->fetchAll(), + ); + } } From e83128928b4270e737baacfcc017453c4c6ebf48 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 16:56:23 +1000 Subject: [PATCH 07/13] Updated test as SQLServer does require conflicts defined --- .../Functional/Driver/SQLServer/Query/UpsertQueryTest.php | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index ab819e3c..b28f1e35 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -14,7 +14,7 @@ final class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlserver'; - protected const QUERY_REQUIRES_CONFLICTS = false; + protected const QUERY_REQUIRES_CONFLICTS = true; 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]);'; From 224aae660cd8740c40e93de80b7f798608a70f74 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 17:19:00 +1000 Subject: [PATCH 08/13] Improved test coverage for Postgres when returning with Fragment --- .../Driver/Postgres/Query/UpsertQueryTest.php | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php index 6878413f..d3a412d1 100644 --- a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php @@ -6,6 +6,7 @@ // phpcs:ignore use Cycle\Database\Driver\Postgres\Query\PostgresUpsertQuery; +use Cycle\Database\Injection\Fragment; use Cycle\Database\Tests\Functional\Driver\Common\Query\UpsertQueryTest as CommonClass; /** @@ -16,4 +17,22 @@ class UpsertQueryTest extends CommonClass { public const DRIVER = 'postgres'; protected const QUERY_INSTANCE = PostgresUpsertQuery::class; + protected const QUERY_WITH_FRAGMENTS_RETURNING = 'INSERT INTO {table} ({email}, {name}, {balance}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {balance} = EXCLUDED.{balance}, {created_at} = EXCLUDED.{created_at}, {updated_at} = EXCLUDED.{updated_at}, {deleted_at} = EXCLUDED.{deleted_at} RETURNING {balance} + 100 as {modified_balance}'; + + public function testQueryWithFragmentsAndReturning(): void + { + $upsert = $this->database->upsert('table') + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + 'created_at' => new Fragment('NOW()'), + 'updated_at' => new Fragment('datetime(\'now\')'), + 'deleted_at' => null, + ])->returning(new Fragment('"balance" + 100 as "modified_balance"')); + + $this->assertSameQuery(static::QUERY_WITH_FRAGMENTS_RETURNING, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', 100, null], $upsert); + } } From 6e0001b6ee46260c90580d43a61543a8b8f7c196 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 17:19:41 +1000 Subject: [PATCH 09/13] Added additional composer utilities for testing and code coverage --- .gitignore | 1 + composer.json | 4 +++- 2 files changed, 4 insertions(+), 1 deletion(-) diff --git a/.gitignore b/.gitignore index b1b372f7..69c3b92a 100644 --- a/.gitignore +++ b/.gitignore @@ -1,4 +1,5 @@ /.idea/ +/.report/ /.dolt/ /runtime/ /vendor/ diff --git a/composer.json b/composer.json index 2b5951b0..6244310d 100644 --- a/composer.json +++ b/composer.json @@ -93,6 +93,8 @@ "cs:fix": "php-cs-fixer fix -v", "psalm": "psalm", "psalm:baseline": "psalm --set-baseline=psalm-baseline.xml", - "test": "phpunit --color=always" + "test": "phpunit --color=always", + "test:coverage": "phpunit --colors=always --coverage-text", + "test:report": "phpunit --do-not-cache-result --log-junit=.report/phpunit.xml --coverage-clover=.report/coverage-clover.xml --coverage-cobertura=.report/coverage-cobertura.xml --coverage-text --colors=never" } } From 9c2fc5279bc6a749acc52e21812961b855fa5703 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 18:30:54 +1000 Subject: [PATCH 10/13] Added support for returning values/fragments whilst upserting with sqlserver --- src/Driver/SQLServer/SQLServerCompiler.php | 23 +++++++++++-- .../SQLServer/Query/UpsertQueryTest.php | 33 +++++++++++++++---- 2 files changed, 47 insertions(+), 9 deletions(-) diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index 21e6da57..f228c06e 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -120,8 +120,8 @@ function (string $column) use ($params, $q, $source) { $tokens['columns'], ); - 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);', + $query = \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), @@ -132,6 +132,25 @@ function (string $column) use ($params, $q, $source) { $this->columns($params, $q, $tokens['columns']), \implode(', ', $inserts), ); + + if (empty($tokens['return'])) { + return $query . ';'; + } + + $output = \array_map( + function (string|FragmentInterface|null $return) use ($params, $q) { + return $return instanceof FragmentInterface + ? $this->fragment($params, $q, $return) + : 'INSERTED.' . $this->name($params, $q, $return); + }, + $tokens['return'], + ); + + return \sprintf( + '%s OUTPUT %s;', + $query, + \implode(', ', $output), + ); } /** diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index b28f1e35..b9881007 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -5,6 +5,7 @@ namespace Cycle\Database\Tests\Functional\Driver\SQLServer\Query; // phpcs:ignore +use Cycle\Database\Injection\Fragment; use Cycle\Database\Tests\Functional\Driver\Common\Query\UpsertQueryTest as CommonClass; /** @@ -14,11 +15,29 @@ final class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlserver'; - protected const QUERY_REQUIRES_CONFLICTS = true; - 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]);'; + protected const QUERY_REQUIRES_CONFLICTS = true; + 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]);'; + protected const QUERY_WITH_FRAGMENTS_RETURNING = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ) AS [source] ([email], [name], [balance], [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].[balance] = [source].[balance], [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], [balance], [created_at], [updated_at], [deleted_at]) VALUES ([source].[email], [source].[name], [source].[balance], [source].[created_at], [source].[updated_at], [source].[deleted_at]) OUTPUT INSERTED.[email], {balance} + 100 AS {modified_balance};'; + + public function testQueryWithFragmentsAndReturning(): void + { + $upsert = $this->database->upsert('table') + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + 'created_at' => new Fragment('NOW()'), + 'updated_at' => new Fragment('datetime(\'now\')'), + 'deleted_at' => null, + ])->returning('email', new Fragment('[balance] + 100 AS [modified_balance]')); + + $this->assertSameQuery(static::QUERY_WITH_FRAGMENTS_RETURNING, $upsert); + $this->assertSameParameters(['adam@email.com', 'Adam', 100, null], $upsert); + } } From d11ff0bc8dc0f48fe053076fa9bb8d9fd44b4d0f Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 18:31:43 +1000 Subject: [PATCH 11/13] Tweaked formatting --- src/Driver/SQLServer/SQLServerCompiler.php | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/src/Driver/SQLServer/SQLServerCompiler.php b/src/Driver/SQLServer/SQLServerCompiler.php index f228c06e..64d562d9 100644 --- a/src/Driver/SQLServer/SQLServerCompiler.php +++ b/src/Driver/SQLServer/SQLServerCompiler.php @@ -137,19 +137,19 @@ function (string $column) use ($params, $q, $source) { return $query . ';'; } - $output = \array_map( + $output = \implode(', ', \array_map( function (string|FragmentInterface|null $return) use ($params, $q) { return $return instanceof FragmentInterface ? $this->fragment($params, $q, $return) : 'INSERTED.' . $this->name($params, $q, $return); }, $tokens['return'], - ); + )); return \sprintf( '%s OUTPUT %s;', $query, - \implode(', ', $output), + $output, ); } From 252895472228ff0fcb175be9c86ee3f8599916f7 Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 19:41:34 +1000 Subject: [PATCH 12/13] Added more test cases and code coverage --- src/Query/UpsertQuery.php | 5 +- .../Driver/Postgres/Query/UpsertQueryTest.php | 99 ++++++++++++++++++- .../SQLServer/Query/UpsertQueryTest.php | 18 ++-- 3 files changed, 105 insertions(+), 17 deletions(-) diff --git a/src/Query/UpsertQuery.php b/src/Query/UpsertQuery.php index 2c61de43..31fc4e28 100644 --- a/src/Query/UpsertQuery.php +++ b/src/Query/UpsertQuery.php @@ -134,11 +134,8 @@ public function run(): mixed ); $lastID = $this->driver->lastInsertID(); - if (\is_numeric($lastID)) { - return (int) $lastID; - } - return $lastID; + return \is_numeric($lastID) ? (int) $lastID : $lastID; } public function getType(): int diff --git a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php index d3a412d1..603db96a 100644 --- a/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/Postgres/Query/UpsertQueryTest.php @@ -6,6 +6,7 @@ // phpcs:ignore use Cycle\Database\Driver\Postgres\Query\PostgresUpsertQuery; +use Cycle\Database\Driver\Postgres\Schema\PostgresColumn; use Cycle\Database\Injection\Fragment; use Cycle\Database\Tests\Functional\Driver\Common\Query\UpsertQueryTest as CommonClass; @@ -15,9 +16,9 @@ */ class UpsertQueryTest extends CommonClass { - public const DRIVER = 'postgres'; - protected const QUERY_INSTANCE = PostgresUpsertQuery::class; - protected const QUERY_WITH_FRAGMENTS_RETURNING = 'INSERT INTO {table} ({email}, {name}, {balance}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {balance} = EXCLUDED.{balance}, {created_at} = EXCLUDED.{created_at}, {updated_at} = EXCLUDED.{updated_at}, {deleted_at} = EXCLUDED.{deleted_at} RETURNING {balance} + 100 as {modified_balance}'; + public const DRIVER = 'postgres'; + protected const QUERY_INSTANCE = PostgresUpsertQuery::class; + protected const QUERY_WITH_RETURNING_FRAGMENT = 'INSERT INTO {table} ({email}, {name}, {balance}, {created_at}, {updated_at}, {deleted_at}) VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ON CONFLICT ({email}) DO UPDATE SET {email} = EXCLUDED.{email}, {name} = EXCLUDED.{name}, {balance} = EXCLUDED.{balance}, {created_at} = EXCLUDED.{created_at}, {updated_at} = EXCLUDED.{updated_at}, {deleted_at} = EXCLUDED.{deleted_at} RETURNING {balance} + 100 as {modified_balance}'; public function testQueryWithFragmentsAndReturning(): void { @@ -32,7 +33,97 @@ public function testQueryWithFragmentsAndReturning(): void 'deleted_at' => null, ])->returning(new Fragment('"balance" + 100 as "modified_balance"')); - $this->assertSameQuery(static::QUERY_WITH_FRAGMENTS_RETURNING, $upsert); + $this->assertSameQuery(static::QUERY_WITH_RETURNING_FRAGMENT, $upsert); $this->assertSameParameters(['adam@email.com', 'Adam', 100, null], $upsert); } + + public function testReturningSingleValueFromDatabase(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $email = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->returning('email') + ->run(); + + $this->assertSame('adam@email.com', $email); + } + + public function testReturningMultipleValuesFromDatabase(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $result = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->returning('email', 'name', 'balance') + ->run(); + + $this->assertSame('adam@email.com', $result['email']); + $this->assertSame('Adam', $result['name']); + $this->assertSame(100, $result['balance']); + } + + public function testNullReturnedWithoutPrimaryKeyAndReturningValues(): void + { + $schema = $this->schema('bar'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('bar'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $result = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->run(); + + $this->assertNull($result); + $this->assertEquals( + [ + ['email' => 'adam@email.com', 'name' => 'Adam', 'balance' => 100], + ], + $table->select()->fetchAll(), + ); + } } diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index b9881007..52369b4b 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -15,14 +15,14 @@ final class UpsertQueryTest extends CommonClass { public const DRIVER = 'sqlserver'; - protected const QUERY_REQUIRES_CONFLICTS = true; - 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]);'; - protected const QUERY_WITH_FRAGMENTS_RETURNING = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ) AS [source] ([email], [name], [balance], [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].[balance] = [source].[balance], [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], [balance], [created_at], [updated_at], [deleted_at]) VALUES ([source].[email], [source].[name], [source].[balance], [source].[created_at], [source].[updated_at], [source].[deleted_at]) OUTPUT INSERTED.[email], {balance} + 100 AS {modified_balance};'; + protected const QUERY_REQUIRES_CONFLICTS = true; + 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]);'; + protected const QUERY_WITH_RETURNING_FRAGMENT = 'MERGE INTO [table] WITH (holdlock) AS [target] USING ( VALUES (?, ?, ?, NOW(), datetime(\'now\'), ?) ) AS [source] ([email], [name], [balance], [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].[balance] = [source].[balance], [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], [balance], [created_at], [updated_at], [deleted_at]) VALUES ([source].[email], [source].[name], [source].[balance], [source].[created_at], [source].[updated_at], [source].[deleted_at]) OUTPUT INSERTED.[email], {balance} + 100 AS {modified_balance};'; public function testQueryWithFragmentsAndReturning(): void { @@ -37,7 +37,7 @@ public function testQueryWithFragmentsAndReturning(): void 'deleted_at' => null, ])->returning('email', new Fragment('[balance] + 100 AS [modified_balance]')); - $this->assertSameQuery(static::QUERY_WITH_FRAGMENTS_RETURNING, $upsert); + $this->assertSameQuery(static::QUERY_WITH_RETURNING_FRAGMENT, $upsert); $this->assertSameParameters(['adam@email.com', 'Adam', 100, null], $upsert); } } From 9a2285af80d8cef43fff061716ce11e0ed0aca3a Mon Sep 17 00:00:00 2001 From: Adam Dyson Date: Fri, 11 Jul 2025 19:48:52 +1000 Subject: [PATCH 13/13] Added more test cases and code coverage --- .../SQLServer/Query/UpsertQueryTest.php | 90 +++++++++++++++++++ 1 file changed, 90 insertions(+) diff --git a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php index 52369b4b..33828969 100644 --- a/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php +++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php @@ -40,4 +40,94 @@ public function testQueryWithFragmentsAndReturning(): void $this->assertSameQuery(static::QUERY_WITH_RETURNING_FRAGMENT, $upsert); $this->assertSameParameters(['adam@email.com', 'Adam', 100, null], $upsert); } + + public function testReturningSingleValueFromDatabase(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $email = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->returning('email') + ->run(); + + $this->assertSame('adam@email.com', $email); + } + + public function testReturningMultipleValuesFromDatabase(): void + { + $schema = $this->schema('foo'); + $schema->primary('id'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('foo'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $result = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->returning('email', 'name', 'balance') + ->run(); + + $this->assertSame('adam@email.com', $result['email']); + $this->assertSame('Adam', $result['name']); + $this->assertSame('100', $result['balance']); + } + + public function testEmptyStringReturnedWithoutPrimaryKeyAndReturningValues(): void + { + $schema = $this->schema('bar'); + $schema->string('name')->nullable(false); + $schema->string('email', 64)->nullable(false); + $schema->integer('balance')->defaultValue(0); + $schema->index(['email'])->unique(true); + $schema->save(); + + $table = $this->database->table('bar'); + + $this->assertTrue($table->exists()); + $this->assertSame(0, $table->count()); + + $result = $table->upsert() + ->conflicts('email') + ->values([ + 'email' => 'adam@email.com', + 'name' => 'Adam', + 'balance' => 100, + ]) + ->run(); + + $this->assertSame('', $result); + $this->assertEquals( + [ + ['email' => 'adam@email.com', 'name' => 'Adam', 'balance' => 100], + ], + $table->select()->fetchAll(), + ); + } }