Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -59,6 +59,7 @@
- Enh #352: Support column's collation (@Tigrov)
- New #358: Add `Connection::getColumnBuilderClass()` method (@Tigrov)
- New #357: Implement `ArrayMergeBuilder`, `LongestBuilder` and `ShortestBuilder` classes (@Tigrov)
- Enh #360: Refactor `DMLQueryBuilder::upsert()` method (@Tigrov)

## 1.3.0 March 21, 2024

Expand Down
29 changes: 7 additions & 22 deletions src/DMLQueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -6,10 +6,10 @@

use InvalidArgumentException;
use Yiisoft\Db\Exception\NotSupportedException;
use Yiisoft\Db\Expression\Expression;
use Yiisoft\Db\Query\QueryInterface;
use Yiisoft\Db\QueryBuilder\AbstractDMLQueryBuilder;

use function array_combine;
use function array_fill;
use function array_key_first;
use function array_map;
Expand Down Expand Up @@ -85,7 +85,7 @@ public function upsert(

foreach ($columnNames as $name) {
$quotedName = $this->quoter->quoteColumnName($name);
$constraintCondition[] = "$quotedTableName.$quotedName=\"EXCLUDED\".$quotedName";
$constraintCondition[] = "$quotedTableName.$quotedName=EXCLUDED.$quotedName";
}

$onCondition[] = $constraintCondition;
Expand All @@ -96,41 +96,26 @@ public function upsert(
[, $placeholders, $values, $params] = $this->prepareInsertValues($table, $insertColumns, $params);

if (!empty($placeholders)) {
$usingSelectValues = [];

foreach ($insertNames as $index => $name) {
$usingSelectValues[$name] = new Expression($placeholders[$index]);
}

$values = $this->queryBuilder->buildSelect($usingSelectValues, $params)
. ' ' . $this->queryBuilder->buildFrom(['DUAL'], $params);
$values = $this->buildSimpleSelect(array_combine($insertNames, $placeholders)) . ' FROM "DUAL"';
}

$insertValues = [];
$quotedInsertNames = array_map($this->quoter->quoteColumnName(...), $insertNames);

foreach ($quotedInsertNames as $quotedName) {
$insertValues[] = '"EXCLUDED".' . $quotedName;
$insertValues[] = 'EXCLUDED.' . $quotedName;
}

$mergeSql = 'MERGE INTO ' . $quotedTableName . ' USING (' . $values . ') "EXCLUDED" ON (' . $on . ')';
$mergeSql = 'MERGE INTO ' . $quotedTableName . ' USING (' . $values . ') EXCLUDED ON (' . $on . ')';
$insertSql = 'INSERT (' . implode(', ', $quotedInsertNames) . ')'
. ' VALUES (' . implode(', ', $insertValues) . ')';

if ($updateColumns === false || $updateNames === []) {
if (empty($updateColumns) || $updateNames === []) {
/** there are no columns to update */
return "$mergeSql WHEN NOT MATCHED THEN $insertSql";
}

if ($updateColumns === true) {
$updateColumns = [];
/** @psalm-var string[] $updateNames */
foreach ($updateNames as $name) {
$updateColumns[$name] = new Expression('"EXCLUDED".' . $this->quoter->quoteColumnName($name));
}
}

$updates = $this->prepareUpdateSets($table, $updateColumns, $params);
$updates = $this->prepareUpsertSets($table, $updateColumns, $updateNames, $params);
$updateSql = 'UPDATE SET ' . implode(', ', $updates);

return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql";
Expand Down
28 changes: 14 additions & 14 deletions tests/Provider/QueryBuilderProvider.php
Original file line number Diff line number Diff line change
Expand Up @@ -137,61 +137,61 @@ public static function upsert(): array
$concreteData = [
'regular values' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "address"=EXCLUDED."address", "status"=EXCLUDED."status", "profile_id"=EXCLUDED."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES (EXCLUDED."email", EXCLUDED."address", EXCLUDED."status", EXCLUDED."profile_id")
SQL,
],
'regular values with unique at not the first position' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "address", :qp1 AS "email", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("address", "email", "status", "profile_id") VALUES ("EXCLUDED"."address", "EXCLUDED"."email", "EXCLUDED"."status", "EXCLUDED"."profile_id")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "address", :qp1 AS "email", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "address"=EXCLUDED."address", "status"=EXCLUDED."status", "profile_id"=EXCLUDED."profile_id" WHEN NOT MATCHED THEN INSERT ("address", "email", "status", "profile_id") VALUES (EXCLUDED."address", EXCLUDED."email", EXCLUDED."status", EXCLUDED."profile_id")
SQL,
],
'regular values with update part' => [
2 => ['address' => 'foo {{city}}', 'status' => 2, 'orders' => new Expression('"T_upsert"."orders" + 1')],
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=:qp5, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=2, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES (EXCLUDED."email", EXCLUDED."address", EXCLUDED."status", EXCLUDED."profile_id")
SQL,
],
'regular values without update part' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES (EXCLUDED."email", EXCLUDED."address", EXCLUDED."status", EXCLUDED."profile_id")
SQL,
],
'query' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name" = :qp0), PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT * FROM PAGINATION WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "status"="EXCLUDED"."status" WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")
SELECT * FROM PAGINATION WHERE rownum <= 1) EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "status"=EXCLUDED."status" WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES (EXCLUDED."email", EXCLUDED."status")
SQL,
],
'query with update part' => [
2 => ['address' => 'foo {{city}}', 'status' => 2, 'orders' => new Expression('"T_upsert"."orders" + 1')],
3 => <<<SQL
MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name" = :qp0), PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT * FROM PAGINATION WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"=:qp1, "status"=:qp2, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")
SELECT * FROM PAGINATION WHERE rownum <= 1) EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "address"=:qp1, "status"=2, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES (EXCLUDED."email", EXCLUDED."status")
SQL,
],
'query without update part' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name" = :qp0), PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT * FROM PAGINATION WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")
SELECT * FROM PAGINATION WHERE rownum <= 1) EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES (EXCLUDED."email", EXCLUDED."status")
SQL,
],
'values and expressions' => [
1 => ['{{%T_upsert}}.[[email]]' => 'dynamic@example.com', '[[ts]]' => new Expression('ROUND((SYSDATE - DATE \'1970-01-01\')*24*60*60)')],
3 => <<<SQL
MERGE INTO {{%T_upsert}} USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"="EXCLUDED"."ts" WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES ("EXCLUDED"."email", "EXCLUDED"."ts")
MERGE INTO {{%T_upsert}} USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") EXCLUDED ON ({{%T_upsert}}."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "ts"=EXCLUDED."ts" WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES (EXCLUDED."email", EXCLUDED."ts")
SQL,
],
'values and expressions with update part' => [
1 => ['{{%T_upsert}}.[[email]]' => 'dynamic@example.com', '[[ts]]' => new Expression('ROUND((SYSDATE - DATE \'1970-01-01\')*24*60*60)')],
2 => ['[[orders]]' => new Expression('"T_upsert"."orders" + 1')],
3 => <<<SQL
MERGE INTO {{%T_upsert}} USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES ("EXCLUDED"."email", "EXCLUDED"."ts")
MERGE INTO {{%T_upsert}} USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") EXCLUDED ON ({{%T_upsert}}."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES (EXCLUDED."email", EXCLUDED."ts")
SQL,
],
'values and expressions without update part' => [
1 => ['{{%T_upsert}}.[[email]]' => 'dynamic@example.com', '[[ts]]' => new Expression('ROUND((SYSDATE - DATE \'1970-01-01\')*24*60*60)')],
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES ("EXCLUDED"."email", "EXCLUDED"."ts")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS "ts" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES (EXCLUDED."email", EXCLUDED."ts")
SQL,
],
'query, values and expressions with update part' => [
Expand All @@ -204,7 +204,7 @@ public static function upsert(): array
)->from('DUAL'),
2 => ['ts' => 0, '[[orders]]' => new Expression('"T_upsert"."orders" + 1')],
3 => <<<SQL
MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS [[ts]] FROM "DUAL") "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"=:qp1, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", [[ts]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[ts]])
MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS [[ts]] FROM "DUAL") EXCLUDED ON ({{%T_upsert}}."email"=EXCLUDED."email") WHEN MATCHED THEN UPDATE SET "ts"=0, "orders"="T_upsert"."orders" + 1 WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES (EXCLUDED."email", EXCLUDED."ts")
SQL,
],
'query, values and expressions without update part' => [
Expand All @@ -216,17 +216,17 @@ public static function upsert(): array
],
)->from('DUAL'),
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :phEmail AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS [[ts]] FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", [[ts]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[ts]])
MERGE INTO "T_upsert" USING (SELECT :phEmail AS "email", ROUND((SYSDATE - DATE '1970-01-01')*24*60*60) AS [[ts]] FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN NOT MATCHED THEN INSERT ("email", "ts") VALUES (EXCLUDED."email", EXCLUDED."ts")
SQL,
],
'no columns to update' => [
3 => <<<SQL
MERGE INTO "T_upsert_1" USING (SELECT :qp0 AS "a" FROM "DUAL") "EXCLUDED" ON ("T_upsert_1"."a"="EXCLUDED"."a") WHEN NOT MATCHED THEN INSERT ("a") VALUES ("EXCLUDED"."a")
MERGE INTO "T_upsert_1" USING (SELECT :qp0 AS "a" FROM "DUAL") EXCLUDED ON ("T_upsert_1"."a"=EXCLUDED."a") WHEN NOT MATCHED THEN INSERT ("a") VALUES (EXCLUDED."a")
SQL,
],
'no columns to update with unique' => [
3 => <<<SQL
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email") VALUES ("EXCLUDED"."email")
MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email" FROM "DUAL") EXCLUDED ON ("T_upsert"."email"=EXCLUDED."email") WHEN NOT MATCHED THEN INSERT ("email") VALUES (EXCLUDED."email")
SQL,
],
'no unique columns in table - simple insert' => [
Expand Down
2 changes: 1 addition & 1 deletion tests/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -484,7 +484,7 @@ public function testUpdate(
array|string $condition,
array $params,
string $expectedSql,
array $expectedParams,
array $expectedParams = [],
): void {
parent::testUpdate($table, $columns, $condition, $params, $expectedSql, $expectedParams);
}
Expand Down