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"
}
}
diff --git a/psalm-baseline.xml b/psalm-baseline.xml
index 4440ea0a..0a29a615 100644
--- a/psalm-baseline.xml
+++ b/psalm-baseline.xml
@@ -296,8 +296,14 @@
+
+
+
+
+
+
@@ -366,6 +372,7 @@
+
@@ -379,8 +386,11 @@
+
+
+
@@ -405,9 +415,11 @@
+
+
@@ -770,9 +782,23 @@
+
+
+
+
+
+
+
+
+
+
+
+
+
+
@@ -793,6 +819,7 @@
new QueryBuilder(
new MySQLSelectQuery(),
new InsertQuery(),
+ new UpsertQuery(),
new MySQLUpdateQuery(),
new MySQLDeleteQuery(),
),
@@ -901,12 +928,12 @@
+
-
@@ -914,6 +941,7 @@
+
@@ -1097,6 +1125,7 @@
+
@@ -1106,9 +1135,11 @@
+
+
@@ -1145,6 +1176,7 @@
new QueryBuilder(
new PostgresSelectQuery(),
new PostgresInsertQuery(),
+ new PostgresUpsertQuery(),
new PostgresUpdateQuery(),
new PostgresDeleteQuery(),
),
@@ -1234,6 +1266,31 @@
+
+
+
+
+
+ returning]]>
+
+
+ fetch(StatementInterface::FETCH_ASSOC)]]>
+ fetchColumn()]]>
+ fetchColumn()]]>
+
+
+
+
+
+ prefix]]>
+
+
+
+
+
+
+
+
@@ -1303,10 +1360,10 @@
+
-
@@ -1321,6 +1378,7 @@
+
@@ -1330,7 +1388,6 @@
-
+
+
+
+
+
+ fetch(StatementInterface::FETCH_ASSOC)]]>
+ fetchColumn()]]>
+
+
+
+
+
+
+
+
+
+
+
@@ -1652,6 +1727,13 @@
+
+
+
+
+
+
+
@@ -1662,6 +1744,7 @@
+
@@ -1678,6 +1761,7 @@
+
@@ -1691,6 +1775,8 @@
+
+
@@ -1708,8 +1794,10 @@
+
+
@@ -1746,6 +1834,7 @@
new QueryBuilder(
new SQLServerSelectQuery(),
new SQLServerInsertQuery(),
+ new SQLServerUpsertQuery(),
new SQLServerUpdateQuery(),
new SQLServerDeleteQuery(),
),
@@ -2059,6 +2148,7 @@
new QueryBuilder(
new SQLiteSelectQuery(),
new InsertQuery(),
+ new UpsertQuery(),
new SQLiteUpdateQuery(),
new SQLiteDeleteQuery(),
),
@@ -2424,6 +2514,14 @@
+
+
+
+
+
+ getParameters()]]>
+
+
prefix]]>
@@ -2521,6 +2619,7 @@
+
@@ -2656,6 +2755,23 @@
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
getAbstractType()]]>
@@ -2930,9 +3046,15 @@
->insert($this->name)
->values($rowset)
->run()]]>
+ database
+ ->upsert($this->name)
+ ->conflicts($conflicts)
+ ->values($rowset)
+ ->run()]]>
+
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/MySQL/Schema/MySQLColumn.php b/src/Driver/MySQL/Schema/MySQLColumn.php
index c8cf6464..ad823afa 100644
--- a/src/Driver/MySQL/Schema/MySQLColumn.php
+++ b/src/Driver/MySQL/Schema/MySQLColumn.php
@@ -112,6 +112,7 @@ class MySQLColumn extends AbstractColumn
//Additional types
'json' => 'json',
+ 'ulid' => ['type' => 'varchar', 'size' => 26],
'uuid' => ['type' => 'varchar', 'size' => 36],
];
protected array $reverseMapping = [
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/Postgres/Schema/PostgresColumn.php b/src/Driver/Postgres/Schema/PostgresColumn.php
index 49bc1cc1..f726c203 100644
--- a/src/Driver/Postgres/Schema/PostgresColumn.php
+++ b/src/Driver/Postgres/Schema/PostgresColumn.php
@@ -181,6 +181,7 @@ class PostgresColumn extends AbstractColumn
//Additional types
'json' => 'json',
'jsonb' => 'jsonb',
+ 'ulid' => ['type' => 'character varying', 'size' => 26],
'uuid' => 'uuid',
'point' => 'point',
'line' => 'line',
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..64d562d9 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,90 @@ 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'],
+ );
+
+ $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),
+ $this->name($params, $q, 'source'),
+ $this->columns($params, $q, $tokens['columns']),
+ \implode(' AND ', $conflicts),
+ \implode(', ', $updates),
+ $this->columns($params, $q, $tokens['columns']),
+ \implode(', ', $inserts),
+ );
+
+ if (empty($tokens['return'])) {
+ return $query . ';';
+ }
+
+ $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,
+ $output,
+ );
+ }
+
/**
* {@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/SQLServer/Schema/SQLServerColumn.php b/src/Driver/SQLServer/Schema/SQLServerColumn.php
index d8b47681..9e960698 100644
--- a/src/Driver/SQLServer/Schema/SQLServerColumn.php
+++ b/src/Driver/SQLServer/Schema/SQLServerColumn.php
@@ -98,6 +98,7 @@ class SQLServerColumn extends AbstractColumn
//Additional types
'json' => ['type' => 'varchar', 'size' => 0],
+ 'ulid' => ['type' => 'varchar', 'size' => 26],
'uuid' => ['type' => 'varchar', 'size' => 36],
];
protected array $reverseMapping = [
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/Driver/SQLite/Schema/SQLiteColumn.php b/src/Driver/SQLite/Schema/SQLiteColumn.php
index 25eec9e5..cef671e0 100644
--- a/src/Driver/SQLite/Schema/SQLiteColumn.php
+++ b/src/Driver/SQLite/Schema/SQLiteColumn.php
@@ -87,6 +87,7 @@ class SQLiteColumn extends AbstractColumn
//Additional types
'json' => 'text',
+ 'ulid' => ['type' => 'varchar', 'size' => 26],
'uuid' => ['type' => 'varchar', 'size' => 36],
];
protected array $reverseMapping = [
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..31fc4e28
--- /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;
+ }
+
+ /**
+ * 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();
+
+ return \is_numeric($lastID) ? (int) $lastID : $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/Schema/AbstractColumn.php b/src/Schema/AbstractColumn.php
index f83ceb79..283d29ad 100644
--- a/src/Schema/AbstractColumn.php
+++ b/src/Schema/AbstractColumn.php
@@ -50,6 +50,7 @@
* @method $this|AbstractColumn tinyBinary()
* @method $this|AbstractColumn longBinary()
* @method $this|AbstractColumn json()
+ * @method $this|AbstractColumn ulid()
* @method $this|AbstractColumn uuid()
*/
abstract class AbstractColumn implements ColumnInterface, ElementInterface
diff --git a/src/Schema/AbstractTable.php b/src/Schema/AbstractTable.php
index 5e495d94..a0eb97ac 100644
--- a/src/Schema/AbstractTable.php
+++ b/src/Schema/AbstractTable.php
@@ -51,6 +51,7 @@
* @method AbstractColumn binary($column)
* @method AbstractColumn tinyBinary($column)
* @method AbstractColumn longBinary($column)
+ * @method AbstractColumn ulid($column)
* @method AbstractColumn uuid($column)
*/
abstract class AbstractTable implements TableInterface, ElementInterface
diff --git a/src/Table.php b/src/Table.php
index ba5b3884..acf494bc 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,44 @@ 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]);
+ * $table->upsertOne(["name" => "Wolfy-J", "balance" => 10], 'name');
+ *
+ * @throws BuilderException
+ */
+ public function upsertOne(array $rowset = [], array|string $conflicts = []): int|string|null
+ {
+ return $this->database
+ ->upsert($this->name)
+ ->conflicts($conflicts)
+ ->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 = [], array|string $conflicts = []): void
+ {
+ $this->database
+ ->upsert($this->name)
+ ->conflicts($conflicts)
+ ->columns($columns)
+ ->values($rowsets)
+ ->run();
+ }
+
/**
* Get insert builder specific to current table.
*/
@@ -135,6 +174,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.
*/
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/Common/Schema/ConsistencyTest.php b/tests/Database/Functional/Driver/Common/Schema/ConsistencyTest.php
index 5074c9b5..bf313737 100644
--- a/tests/Database/Functional/Driver/Common/Schema/ConsistencyTest.php
+++ b/tests/Database/Functional/Driver/Common/Schema/ConsistencyTest.php
@@ -360,6 +360,64 @@ public function testTime(): void
$this->assertTrue($schema->column('target')->compare($column));
}
+ public function testUlid(): void
+ {
+ $schema = $this->schema('table');
+ $this->assertFalse($schema->exists());
+
+ $column = $schema->ulid('target');
+
+ $schema->save();
+
+ $schema = $this->schema('table');
+ $this->assertTrue($schema->exists());
+ $this->assertTrue($schema->column('target')->compare($column));
+ $this->assertSame('string', $schema->column('target')->getType());
+
+ $this->database->table('table')->insertOne(
+ [
+ 'target' => '0GWWXY2G84DFMRVWQNJ1SRYCMC',
+ ],
+ );
+
+ $this->assertEquals(
+ [
+ 'target' => '0GWWXY2G84DFMRVWQNJ1SRYCMC',
+ ],
+ $this->database->table('table')->select()->fetchAll()[0],
+ );
+ }
+
+ public function testUlidPrimary(): void
+ {
+ $schema = $this->schema('table');
+ $this->assertFalse($schema->exists());
+
+ $column = $schema->ulid('target')->nullable(false);
+ $schema->setPrimaryKeys(['target']);
+ $schema->save();
+
+ $schema = $this->schema('table');
+ $this->assertTrue($schema->exists());
+
+ $this->assertTrue($schema->column('target')->compare($column));
+ $this->assertSame('string', $schema->column('target')->getType());
+ $this->assertSame(['target'], $schema->getPrimaryKeys());
+
+ $this->database->table('table')->insertOne(
+ [
+ 'target' => '0GWWXY2G84DFMRVWQNJ1SRYCMC',
+ ],
+ );
+
+ $this->assertEquals(
+ [
+ 'target' => '0GWWXY2G84DFMRVWQNJ1SRYCMC',
+ ],
+ $this->database->table('table')->select()->fetchAll()[0],
+ );
+ }
+
public function testUuid(): void
{
$schema = $this->schema('table');
diff --git a/tests/Database/Functional/Driver/Common/Schema/TableTest.php b/tests/Database/Functional/Driver/Common/Schema/TableTest.php
index 575dbf68..71ac5c9e 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
*/
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 @@
+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_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/Postgres/Schema/TableTest.php b/tests/Database/Functional/Driver/Postgres/Schema/TableTest.php
index 95b3900a..22544319 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(),
+ );
+ }
}
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..289d1fb9
--- /dev/null
+++ b/tests/Database/Functional/Driver/SQLServer/Query/UpsertQueryTest.php
@@ -0,0 +1,133 @@
+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(self::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(),
+ );
+ }
+}
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..b33597d7
--- /dev/null
+++ b/tests/Database/Functional/Driver/SQLite/Query/UpsertQueryTest.php
@@ -0,0 +1,17 @@
+