diff --git a/src/BaseSeed.php b/src/BaseSeed.php index 85532272..cc0e1728 100644 --- a/src/BaseSeed.php +++ b/src/BaseSeed.php @@ -191,6 +191,16 @@ public function insertOrSkip(string $tableName, array $data): void $table->insertOrSkip($data)->save(); } + /** + * {@inheritDoc} + */ + public function insertOrUpdate(string $tableName, array $data, array $updateColumns, array $conflictColumns): void + { + // convert to table object + $table = new Table($tableName, [], $this->getAdapter()); + $table->insertOrUpdate($data, $updateColumns, $conflictColumns)->save(); + } + /** * {@inheritDoc} */ diff --git a/src/Db/Adapter/AbstractAdapter.php b/src/Db/Adapter/AbstractAdapter.php index 7251ba31..f8d14125 100644 --- a/src/Db/Adapter/AbstractAdapter.php +++ b/src/Db/Adapter/AbstractAdapter.php @@ -622,9 +622,14 @@ public function fetchAll(string $sql): array /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void - { - $sql = $this->generateInsertSql($table, $row, $mode); + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $sql = $this->generateInsertSql($table, $row, $mode, $updateColumns, $conflictColumns); if ($this->isDryRunEnabled()) { $this->io->out($sql); @@ -649,10 +654,17 @@ public function insert(TableMetadata $table, array $row, ?InsertMode $mode = nul * @param \Migrations\Db\Table\TableMetadata $table The table to insert into * @param array $row The row to insert * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on upsert conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert (unused in MySQL) * @return string */ - protected function generateInsertSql(TableMetadata $table, array $row, ?InsertMode $mode = null): string - { + protected function generateInsertSql( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): string { $sql = sprintf( '%s INTO %s ', $this->getInsertPrefix($mode), @@ -667,8 +679,10 @@ protected function generateInsertSql(TableMetadata $table, array $row, ?InsertMo } } + $upsertClause = $this->getUpsertClause($mode, $updateColumns, $conflictColumns); + if ($this->isDryRunEnabled()) { - $sql .= ' VALUES (' . implode(', ', array_map($this->quoteValue(...), $row)) . ');'; + $sql .= ' VALUES (' . implode(', ', array_map($this->quoteValue(...), $row)) . ')' . $upsertClause . ';'; return $sql; } else { @@ -680,7 +694,7 @@ protected function generateInsertSql(TableMetadata $table, array $row, ?InsertMo } $values[] = $placeholder; } - $sql .= ' VALUES (' . implode(',', $values) . ')'; + $sql .= ' VALUES (' . implode(',', $values) . ')' . $upsertClause; return $sql; } @@ -701,6 +715,29 @@ protected function getInsertPrefix(?InsertMode $mode = null): string return 'INSERT'; } + /** + * Get the upsert clause for MySQL (ON DUPLICATE KEY UPDATE). + * + * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on conflict + * @param array|null $conflictColumns Columns that define uniqueness (unused in MySQL) + * @return string + */ + protected function getUpsertClause(?InsertMode $mode, ?array $updateColumns, ?array $conflictColumns = null): string + { + if ($mode !== InsertMode::UPSERT || $updateColumns === null) { + return ''; + } + + $updates = []; + foreach ($updateColumns as $column) { + $quotedColumn = $this->quoteColumnName($column); + $updates[] = $quotedColumn . ' = VALUES(' . $quotedColumn . ')'; + } + + return ' ON DUPLICATE KEY UPDATE ' . implode(', ', $updates); + } + /** * Quotes a database value. * @@ -748,9 +785,14 @@ protected function quoteString(string $value): string /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void - { - $sql = $this->generateBulkInsertSql($table, $rows, $mode); + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $sql = $this->generateBulkInsertSql($table, $rows, $mode, $updateColumns, $conflictColumns); if ($this->isDryRunEnabled()) { $this->io->out($sql); @@ -785,10 +827,17 @@ public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode * @param \Migrations\Db\Table\TableMetadata $table The table to insert into * @param array $rows The rows to insert * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on upsert conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert (unused in MySQL) * @return string */ - protected function generateBulkInsertSql(TableMetadata $table, array $rows, ?InsertMode $mode = null): string - { + protected function generateBulkInsertSql( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): string { $sql = sprintf( '%s INTO %s ', $this->getInsertPrefix($mode), @@ -799,11 +848,13 @@ protected function generateBulkInsertSql(TableMetadata $table, array $rows, ?Ins $sql .= '(' . implode(', ', array_map($this->quoteColumnName(...), $keys)) . ') VALUES '; + $upsertClause = $this->getUpsertClause($mode, $updateColumns, $conflictColumns); + if ($this->isDryRunEnabled()) { $values = array_map(function ($row) { return '(' . implode(', ', array_map($this->quoteValue(...), $row)) . ')'; }, $rows); - $sql .= implode(', ', $values) . ';'; + $sql .= implode(', ', $values) . $upsertClause . ';'; return $sql; } else { @@ -820,7 +871,7 @@ protected function generateBulkInsertSql(TableMetadata $table, array $rows, ?Ins $query = '(' . implode(', ', $values) . ')'; $queries[] = $query; } - $sql .= implode(',', $queries); + $sql .= implode(',', $queries) . $upsertClause; return $sql; } diff --git a/src/Db/Adapter/AdapterInterface.php b/src/Db/Adapter/AdapterInterface.php index 15c30fe9..0b60f059 100644 --- a/src/Db/Adapter/AdapterInterface.php +++ b/src/Db/Adapter/AdapterInterface.php @@ -480,9 +480,17 @@ public function fetchAll(string $sql): array; * @param \Migrations\Db\Table\TableMetadata $table Table where to insert data * @param array $row Row * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on upsert conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert * @return void */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void; + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void; /** * Inserts data into a table in a bulk. @@ -490,9 +498,17 @@ public function insert(TableMetadata $table, array $row, ?InsertMode $mode = nul * @param \Migrations\Db\Table\TableMetadata $table Table where to insert data * @param array $rows Rows * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on upsert conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert * @return void */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void; + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void; /** * Quotes a table name for use in a query. diff --git a/src/Db/Adapter/AdapterWrapper.php b/src/Db/Adapter/AdapterWrapper.php index a291db0f..f8dd0480 100644 --- a/src/Db/Adapter/AdapterWrapper.php +++ b/src/Db/Adapter/AdapterWrapper.php @@ -138,17 +138,27 @@ public function query(string $sql, array $params = []): mixed /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void - { - $this->getAdapter()->insert($table, $row, $mode); + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $this->getAdapter()->insert($table, $row, $mode, $updateColumns, $conflictColumns); } /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void - { - $this->getAdapter()->bulkinsert($table, $rows, $mode); + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $this->getAdapter()->bulkinsert($table, $rows, $mode, $updateColumns, $conflictColumns); } /** diff --git a/src/Db/Adapter/PostgresAdapter.php b/src/Db/Adapter/PostgresAdapter.php index 6ec16ce0..165cfa21 100644 --- a/src/Db/Adapter/PostgresAdapter.php +++ b/src/Db/Adapter/PostgresAdapter.php @@ -1152,8 +1152,13 @@ public function setSearchPath(): void /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void - { + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { $sql = sprintf( 'INSERT INTO %s ', $this->quoteTableName($table->getName()), @@ -1172,7 +1177,7 @@ public function insert(TableMetadata $table, array $row, ?InsertMode $mode = nul $override = self::OVERRIDE_SYSTEM_VALUE . ' '; } - $conflictClause = $this->getConflictClause($mode); + $conflictClause = $this->getConflictClause($mode, $updateColumns, $conflictColumns); if ($this->isDryRunEnabled()) { $sql .= ' ' . $override . 'VALUES (' . implode(', ', array_map($this->quoteValue(...), $row)) . ')' . $conflictClause . ';'; @@ -1198,8 +1203,13 @@ public function insert(TableMetadata $table, array $row, ?InsertMode $mode = nul /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void - { + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { $sql = sprintf( 'INSERT INTO %s ', $this->quoteTableName($table->getName()), @@ -1215,7 +1225,7 @@ public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode $sql .= '(' . implode(', ', array_map($this->quoteColumnName(...), $keys)) . ') ' . $override . 'VALUES '; - $conflictClause = $this->getConflictClause($mode); + $conflictClause = $this->getConflictClause($mode, $updateColumns, $conflictColumns); if ($this->isDryRunEnabled()) { $values = array_map(function ($row) { @@ -1258,14 +1268,30 @@ public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode * Get the ON CONFLICT clause based on insert mode. * * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on upsert conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert * @return string */ - protected function getConflictClause(?InsertMode $mode = null): string - { + protected function getConflictClause( + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): string { if ($mode === InsertMode::IGNORE) { return ' ON CONFLICT DO NOTHING'; } + if ($mode === InsertMode::UPSERT && $updateColumns !== null && $conflictColumns !== null) { + $quotedConflictColumns = array_map($this->quoteColumnName(...), $conflictColumns); + $updates = []; + foreach ($updateColumns as $column) { + $quotedColumn = $this->quoteColumnName($column); + $updates[] = $quotedColumn . ' = EXCLUDED.' . $quotedColumn; + } + + return ' ON CONFLICT (' . implode(', ', $quotedConflictColumns) . ') DO UPDATE SET ' . implode(', ', $updates); + } + return ''; } diff --git a/src/Db/Adapter/SqliteAdapter.php b/src/Db/Adapter/SqliteAdapter.php index 4c163755..0b49ded8 100644 --- a/src/Db/Adapter/SqliteAdapter.php +++ b/src/Db/Adapter/SqliteAdapter.php @@ -1702,4 +1702,28 @@ protected function getInsertPrefix(?InsertMode $mode = null): string return 'INSERT'; } + + /** + * Get the upsert clause for SQLite (ON CONFLICT ... DO UPDATE SET). + * + * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @param array|null $updateColumns Columns to update on conflict + * @param array|null $conflictColumns Columns that define uniqueness for upsert + * @return string + */ + protected function getUpsertClause(?InsertMode $mode, ?array $updateColumns, ?array $conflictColumns = null): string + { + if ($mode !== InsertMode::UPSERT || $updateColumns === null || $conflictColumns === null) { + return ''; + } + + $quotedConflictColumns = array_map($this->quoteColumnName(...), $conflictColumns); + $updates = []; + foreach ($updateColumns as $column) { + $quotedColumn = $this->quoteColumnName($column); + $updates[] = $quotedColumn . ' = excluded.' . $quotedColumn; + } + + return ' ON CONFLICT (' . implode(', ', $quotedConflictColumns) . ') DO UPDATE SET ' . implode(', ', $updates); + } } diff --git a/src/Db/Adapter/SqlserverAdapter.php b/src/Db/Adapter/SqlserverAdapter.php index ec3c0fc0..71301bfe 100644 --- a/src/Db/Adapter/SqlserverAdapter.php +++ b/src/Db/Adapter/SqlserverAdapter.php @@ -1007,9 +1007,14 @@ public function migrated(MigrationInterface $migration, string $direction, strin /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void - { - $sql = $this->generateInsertSql($table, $row, $mode); + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $sql = $this->generateInsertSql($table, $row, $mode, $updateColumns, $conflictColumns); $sql = $this->updateSQLForIdentityInsert($table->getName(), $sql); @@ -1033,9 +1038,14 @@ public function insert(TableMetadata $table, array $row, ?InsertMode $mode = nul /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void - { - $sql = $this->generateBulkInsertSql($table, $rows, $mode); + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { + $sql = $this->generateBulkInsertSql($table, $rows, $mode, $updateColumns, $conflictColumns); $sql = $this->updateSQLForIdentityInsert($table->getName(), $sql); diff --git a/src/Db/Adapter/TimedOutputAdapter.php b/src/Db/Adapter/TimedOutputAdapter.php index b356403d..f5e11be6 100644 --- a/src/Db/Adapter/TimedOutputAdapter.php +++ b/src/Db/Adapter/TimedOutputAdapter.php @@ -84,22 +84,32 @@ function ($value) { /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void - { + public function insert( + TableMetadata $table, + array $row, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { $end = $this->startCommandTimer(); $this->writeCommand('insert', [$table->getName()]); - parent::insert($table, $row, $mode); + parent::insert($table, $row, $mode, $updateColumns, $conflictColumns); $end(); } /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void - { + public function bulkinsert( + TableMetadata $table, + array $rows, + ?InsertMode $mode = null, + ?array $updateColumns = null, + ?array $conflictColumns = null, + ): void { $end = $this->startCommandTimer(); $this->writeCommand('bulkinsert', [$table->getName()]); - parent::bulkinsert($table, $rows, $mode); + parent::bulkinsert($table, $rows, $mode, $updateColumns, $conflictColumns); $end(); } diff --git a/src/Db/InsertMode.php b/src/Db/InsertMode.php index 6a77eeff..e04b707c 100644 --- a/src/Db/InsertMode.php +++ b/src/Db/InsertMode.php @@ -28,4 +28,13 @@ enum InsertMode: string * - SQLite: INSERT OR IGNORE */ case IGNORE = 'ignore'; + + /** + * UPSERT - inserts or updates rows on duplicate key conflicts + * + * - MySQL: ON DUPLICATE KEY UPDATE + * - PostgreSQL: ON CONFLICT (...) DO UPDATE SET + * - SQLite: ON CONFLICT (...) DO UPDATE SET + */ + case UPSERT = 'upsert'; } diff --git a/src/Db/Table.php b/src/Db/Table.php index 852d1ecd..6bf0021b 100644 --- a/src/Db/Table.php +++ b/src/Db/Table.php @@ -73,6 +73,20 @@ class Table */ protected ?InsertMode $insertMode = null; + /** + * Columns to update on upsert conflict + * + * @var array|null + */ + protected ?array $upsertUpdateColumns = null; + + /** + * Columns that define uniqueness for upsert conflict detection + * + * @var array|null + */ + protected ?array $upsertConflictColumns = null; + /** * Primary key for this table. * Can either be a string or an array in case of composite @@ -703,6 +717,34 @@ public function insertOrSkip(array $data) return $this->insert($data); } + /** + * Insert data into the table, updating specified columns on duplicate key conflicts. + * + * This method performs an "upsert" operation - inserting new rows and updating + * existing rows that conflict on the specified unique columns. + * + * Example: + * ```php + * $table->insertOrUpdate([ + * ['code' => 'USD', 'rate' => 1.0000], + * ['code' => 'EUR', 'rate' => 0.9234], + * ], ['rate'], ['code']); + * ``` + * + * @param array $data array of data in the same format as insert() + * @param array $updateColumns Columns to update when a conflict occurs + * @param array $conflictColumns Columns that define uniqueness (must have unique index) + * @return $this + */ + public function insertOrUpdate(array $data, array $updateColumns, array $conflictColumns) + { + $this->insertMode = InsertMode::UPSERT; + $this->upsertUpdateColumns = $updateColumns; + $this->upsertConflictColumns = $conflictColumns; + + return $this->insert($data); + } + /** * Creates a table from the object instance. * @@ -822,15 +864,29 @@ public function saveData(): void } if ($bulk) { - $this->getAdapter()->bulkinsert($this->table, $this->getData(), $this->insertMode); + $this->getAdapter()->bulkinsert( + $this->table, + $this->getData(), + $this->insertMode, + $this->upsertUpdateColumns, + $this->upsertConflictColumns, + ); } else { foreach ($this->getData() as $row) { - $this->getAdapter()->insert($this->table, $row, $this->insertMode); + $this->getAdapter()->insert( + $this->table, + $row, + $this->insertMode, + $this->upsertUpdateColumns, + $this->upsertConflictColumns, + ); } } $this->resetData(); $this->insertMode = null; + $this->upsertUpdateColumns = null; + $this->upsertConflictColumns = null; } /** diff --git a/src/SeedInterface.php b/src/SeedInterface.php index 6bc6a2b9..f566484f 100644 --- a/src/SeedInterface.php +++ b/src/SeedInterface.php @@ -155,6 +155,23 @@ public function insert(string $tableName, array $data): void; */ public function insertOrSkip(string $tableName, array $data): void; + /** + * Insert data into a table, updating specified columns on duplicate key conflicts. + * + * This method performs an "upsert" operation - inserting new rows and updating + * existing rows that conflict on the specified unique columns. + * + * Uses ON DUPLICATE KEY UPDATE (MySQL), or ON CONFLICT ... DO UPDATE SET + * (PostgreSQL/SQLite). + * + * @param string $tableName Table name + * @param array $data Data + * @param array $updateColumns Columns to update when a conflict occurs + * @param array $conflictColumns Columns that define uniqueness (must have unique index) + * @return void + */ + public function insertOrUpdate(string $tableName, array $data, array $updateColumns, array $conflictColumns): void; + /** * Checks to see if a table exists. * diff --git a/tests/TestCase/Db/Adapter/MysqlAdapterTest.php b/tests/TestCase/Db/Adapter/MysqlAdapterTest.php index 2f5b1d65..083d505c 100644 --- a/tests/TestCase/Db/Adapter/MysqlAdapterTest.php +++ b/tests/TestCase/Db/Adapter/MysqlAdapterTest.php @@ -2973,4 +2973,82 @@ public function testAlgorithmWithMixedCase() $this->assertTrue($this->adapter->hasColumn('mixed_case', 'col2')); } + + public function testInsertOrUpdateWithDuplicates() + { + $table = new Table('currencies', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 3]) + ->addColumn('rate', 'decimal', ['precision' => 10, 'scale' => 4]) + ->addIndex('code', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0000], + ['code' => 'EUR', 'rate' => 0.9000], + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(2, $rows); + $this->assertEquals('0.9000', $rows[0]['rate']); // EUR + $this->assertEquals('1.0000', $rows[1]['rate']); // USD + + // Update rates - should update existing rows + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0500], + ['code' => 'EUR', 'rate' => 0.9234], + ['code' => 'GBP', 'rate' => 0.7800], // New row + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(3, $rows); + $this->assertEquals('0.9234', $rows[0]['rate']); // EUR updated + $this->assertEquals('0.7800', $rows[1]['rate']); // GBP new + $this->assertEquals('1.0500', $rows[2]['rate']); // USD updated + } + + public function testInsertOrUpdateWithMultipleUpdateColumns() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addColumn('stock', 'integer') + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 10.00, 'stock' => 100], + ], ['price', 'stock'], ['sku'])->save(); + + // Update both price and stock + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 15.00, 'stock' => 50], + ], ['price', 'stock'], ['sku'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products'); + $this->assertCount(1, $rows); + $this->assertEquals('15.00', $rows[0]['price']); + $this->assertEquals(50, $rows[0]['stock']); + } + + public function testInsertOrUpdateModeResetsAfterSave() + { + $table = new Table('items', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 10]) + ->addColumn('name', 'string') + ->addIndex('code', ['unique' => true]) + ->create(); + + // Use insertOrUpdate + $table->insertOrUpdate([ + ['code' => 'ITEM1', 'name' => 'Item One'], + ], ['name'], ['code'])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['code' => 'ITEM1', 'name' => 'Different Name'], + ])->save(); + } } diff --git a/tests/TestCase/Db/Adapter/PostgresAdapterTest.php b/tests/TestCase/Db/Adapter/PostgresAdapterTest.php index 56edf447..c832b84e 100644 --- a/tests/TestCase/Db/Adapter/PostgresAdapterTest.php +++ b/tests/TestCase/Db/Adapter/PostgresAdapterTest.php @@ -2905,4 +2905,82 @@ public function testInsertOrSkipWithoutDuplicates() $rows = $this->adapter->fetchAll('SELECT * FROM categories'); $this->assertCount(2, $rows); } + + public function testInsertOrUpdateWithDuplicates() + { + $table = new Table('currencies', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 3]) + ->addColumn('rate', 'decimal', ['precision' => 10, 'scale' => 4]) + ->addIndex('code', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0000], + ['code' => 'EUR', 'rate' => 0.9000], + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(2, $rows); + $this->assertEquals('0.9000', $rows[0]['rate']); // EUR + $this->assertEquals('1.0000', $rows[1]['rate']); // USD + + // Update rates - should update existing rows + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0500], + ['code' => 'EUR', 'rate' => 0.9234], + ['code' => 'GBP', 'rate' => 0.7800], // New row + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(3, $rows); + $this->assertEquals('0.9234', $rows[0]['rate']); // EUR updated + $this->assertEquals('0.7800', $rows[1]['rate']); // GBP new + $this->assertEquals('1.0500', $rows[2]['rate']); // USD updated + } + + public function testInsertOrUpdateWithMultipleUpdateColumns() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addColumn('stock', 'integer') + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 10.00, 'stock' => 100], + ], ['price', 'stock'], ['sku'])->save(); + + // Update both price and stock + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 15.00, 'stock' => 50], + ], ['price', 'stock'], ['sku'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products'); + $this->assertCount(1, $rows); + $this->assertEquals('15.00', $rows[0]['price']); + $this->assertEquals(50, $rows[0]['stock']); + } + + public function testInsertOrUpdateModeResetsAfterSave() + { + $table = new Table('items', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 10]) + ->addColumn('name', 'string') + ->addIndex('code', ['unique' => true]) + ->create(); + + // Use insertOrUpdate + $table->insertOrUpdate([ + ['code' => 'ITEM1', 'name' => 'Item One'], + ], ['name'], ['code'])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['code' => 'ITEM1', 'name' => 'Different Name'], + ])->save(); + } } diff --git a/tests/TestCase/Db/Adapter/SqliteAdapterTest.php b/tests/TestCase/Db/Adapter/SqliteAdapterTest.php index 5c76b523..1fc925ae 100644 --- a/tests/TestCase/Db/Adapter/SqliteAdapterTest.php +++ b/tests/TestCase/Db/Adapter/SqliteAdapterTest.php @@ -3278,4 +3278,82 @@ public function testInsertOrSkipWithoutDuplicates() $rows = $this->adapter->fetchAll('SELECT * FROM categories'); $this->assertCount(2, $rows); } + + public function testInsertOrUpdateWithDuplicates() + { + $table = new Table('currencies', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 3]) + ->addColumn('rate', 'decimal', ['precision' => 10, 'scale' => 4]) + ->addIndex('code', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0000], + ['code' => 'EUR', 'rate' => 0.9000], + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(2, $rows); + $this->assertEquals('0.9000', $rows[0]['rate']); // EUR + $this->assertEquals('1.0000', $rows[1]['rate']); // USD + + // Update rates - should update existing rows + $table->insertOrUpdate([ + ['code' => 'USD', 'rate' => 1.0500], + ['code' => 'EUR', 'rate' => 0.9234], + ['code' => 'GBP', 'rate' => 0.7800], // New row + ], ['rate'], ['code'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM currencies ORDER BY code'); + $this->assertCount(3, $rows); + $this->assertEquals('0.9234', $rows[0]['rate']); // EUR updated + $this->assertEquals('0.7800', $rows[1]['rate']); // GBP new + $this->assertEquals('1.0500', $rows[2]['rate']); // USD updated + } + + public function testInsertOrUpdateWithMultipleUpdateColumns() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addColumn('stock', 'integer') + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 10.00, 'stock' => 100], + ], ['price', 'stock'], ['sku'])->save(); + + // Update both price and stock + $table->insertOrUpdate([ + ['sku' => 'ABC123', 'price' => 15.00, 'stock' => 50], + ], ['price', 'stock'], ['sku'])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products'); + $this->assertCount(1, $rows); + $this->assertEquals('15.00', $rows[0]['price']); + $this->assertEquals(50, $rows[0]['stock']); + } + + public function testInsertOrUpdateModeResetsAfterSave() + { + $table = new Table('items', [], $this->adapter); + $table->addColumn('code', 'string', ['limit' => 10]) + ->addColumn('name', 'string') + ->addIndex('code', ['unique' => true]) + ->create(); + + // Use insertOrUpdate + $table->insertOrUpdate([ + ['code' => 'ITEM1', 'name' => 'Item One'], + ], ['name'], ['code'])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['code' => 'ITEM1', 'name' => 'Different Name'], + ])->save(); + } }