diff --git a/src/BaseSeed.php b/src/BaseSeed.php index 03d399d72..742559cc8 100644 --- a/src/BaseSeed.php +++ b/src/BaseSeed.php @@ -181,6 +181,16 @@ public function insert(string $tableName, array $data): void $table->insert($data)->save(); } + /** + * {@inheritDoc} + */ + public function insertOrSkip(string $tableName, array $data): void + { + // convert to table object + $table = new Table($tableName, [], $this->getAdapter()); + $table->insertOrSkip($data)->save(); + } + /** * {@inheritDoc} */ diff --git a/src/Db/Adapter/AbstractAdapter.php b/src/Db/Adapter/AbstractAdapter.php index c6a32e7ab..349cf6755 100644 --- a/src/Db/Adapter/AbstractAdapter.php +++ b/src/Db/Adapter/AbstractAdapter.php @@ -35,6 +35,7 @@ use Migrations\Db\Action\RenameColumn; use Migrations\Db\Action\RenameTable; use Migrations\Db\AlterInstructions; +use Migrations\Db\InsertMode; use Migrations\Db\Literal; use Migrations\Db\Table; use Migrations\Db\Table\CheckConstraint; @@ -600,9 +601,9 @@ public function fetchAll(string $sql): array /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row): void + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void { - $sql = $this->generateInsertSql($table, $row); + $sql = $this->generateInsertSql($table, $row, $mode); if ($this->isDryRunEnabled()) { $this->io->out($sql); @@ -626,12 +627,14 @@ public function insert(TableMetadata $table, array $row): void * * @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 * @return string */ - protected function generateInsertSql(TableMetadata $table, array $row): string + protected function generateInsertSql(TableMetadata $table, array $row, ?InsertMode $mode = null): string { $sql = sprintf( - 'INSERT INTO %s ', + '%s INTO %s ', + $this->getInsertPrefix($mode), $this->quoteTableName($table->getName()), ); $columns = array_keys($row); @@ -662,6 +665,21 @@ protected function generateInsertSql(TableMetadata $table, array $row): string } } + /** + * Get the INSERT prefix based on insert mode and database type. + * + * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @return string + */ + protected function getInsertPrefix(?InsertMode $mode = null): string + { + if ($mode === InsertMode::IGNORE) { + return 'INSERT IGNORE'; + } + + return 'INSERT'; + } + /** * Quotes a database value. * @@ -709,9 +727,9 @@ protected function quoteString(string $value): string /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows): void + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void { - $sql = $this->generateBulkInsertSql($table, $rows); + $sql = $this->generateBulkInsertSql($table, $rows, $mode); if ($this->isDryRunEnabled()) { $this->io->out($sql); @@ -745,12 +763,14 @@ public function bulkinsert(TableMetadata $table, array $rows): void * * @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 * @return string */ - protected function generateBulkInsertSql(TableMetadata $table, array $rows): string + protected function generateBulkInsertSql(TableMetadata $table, array $rows, ?InsertMode $mode = null): string { $sql = sprintf( - 'INSERT INTO %s ', + '%s INTO %s ', + $this->getInsertPrefix($mode), $this->quoteTableName($table->getName()), ); $current = current($rows); diff --git a/src/Db/Adapter/AdapterInterface.php b/src/Db/Adapter/AdapterInterface.php index 60fba9305..2cb18f90f 100644 --- a/src/Db/Adapter/AdapterInterface.php +++ b/src/Db/Adapter/AdapterInterface.php @@ -16,6 +16,7 @@ use Cake\Database\Query\SelectQuery; use Cake\Database\Query\UpdateQuery; use Cake\Database\Schema\TableSchemaInterface; +use Migrations\Db\InsertMode; use Migrations\Db\Table\CheckConstraint; use Migrations\Db\Table\Column; use Migrations\Db\Table\TableMetadata; @@ -313,18 +314,20 @@ 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 * @return void */ - public function insert(TableMetadata $table, array $row): void; + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void; /** * Inserts data into a table in a bulk. * * @param \Migrations\Db\Table\TableMetadata $table Table where to insert data * @param array $rows Rows + * @param \Migrations\Db\InsertMode|null $mode Insert mode * @return void */ - public function bulkinsert(TableMetadata $table, array $rows): void; + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = 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 51f726006..7f13d5f61 100644 --- a/src/Db/Adapter/AdapterWrapper.php +++ b/src/Db/Adapter/AdapterWrapper.php @@ -15,6 +15,7 @@ use Cake\Database\Query\InsertQuery; use Cake\Database\Query\SelectQuery; use Cake\Database\Query\UpdateQuery; +use Migrations\Db\InsertMode; use Migrations\Db\Table\CheckConstraint; use Migrations\Db\Table\Column; use Migrations\Db\Table\TableMetadata; @@ -136,17 +137,17 @@ public function query(string $sql, array $params = []): mixed /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row): void + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void { - $this->getAdapter()->insert($table, $row); + $this->getAdapter()->insert($table, $row, $mode); } /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows): void + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void { - $this->getAdapter()->bulkinsert($table, $rows); + $this->getAdapter()->bulkinsert($table, $rows, $mode); } /** diff --git a/src/Db/Adapter/MysqlAdapter.php b/src/Db/Adapter/MysqlAdapter.php index e15fad16e..c27d681ed 100644 --- a/src/Db/Adapter/MysqlAdapter.php +++ b/src/Db/Adapter/MysqlAdapter.php @@ -276,8 +276,8 @@ public function createTable(TableMetadata $table, array $columns = [], array $in * Apply MySQL specific translations between the values using migrations constants/types * and the cakephp/database constants. Over time, these can be aligned. * - * @param array $data The raw column data. - * @return array Modified column data. + * @param array $data The raw column data. + * @return array Modified column data. */ protected function mapColumnData(array $data): array { diff --git a/src/Db/Adapter/PostgresAdapter.php b/src/Db/Adapter/PostgresAdapter.php index 40488eb98..9f792f1e2 100644 --- a/src/Db/Adapter/PostgresAdapter.php +++ b/src/Db/Adapter/PostgresAdapter.php @@ -14,6 +14,7 @@ use Cake\I18n\DateTime; use InvalidArgumentException; use Migrations\Db\AlterInstructions; +use Migrations\Db\InsertMode; use Migrations\Db\Literal; use Migrations\Db\Table\CheckConstraint; use Migrations\Db\Table\Column; @@ -205,8 +206,8 @@ public function createTable(TableMetadata $table, array $columns = [], array $in * Apply postgres specific translations between the values using migrations constants/types * and the cakephp/database constants. Over time, these can be aligned. * - * @param array $data The raw column data. - * @return array Modified column data. + * @param array $data The raw column data. + * @return array Modified column data. */ protected function mapColumnData(array $data): array { @@ -1152,7 +1153,7 @@ public function setSearchPath(): void /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row): void + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void { $sql = sprintf( 'INSERT INTO %s ', @@ -1172,8 +1173,10 @@ public function insert(TableMetadata $table, array $row): void $override = self::OVERRIDE_SYSTEM_VALUE . ' '; } + $conflictClause = $this->getConflictClause($mode); + if ($this->isDryRunEnabled()) { - $sql .= ' ' . $override . 'VALUES (' . implode(', ', array_map($this->quoteValue(...), $row)) . ');'; + $sql .= ' ' . $override . 'VALUES (' . implode(', ', array_map($this->quoteValue(...), $row)) . ')' . $conflictClause . ';'; $this->io->out($sql); } else { $values = []; @@ -1188,7 +1191,7 @@ public function insert(TableMetadata $table, array $row): void $vals[] = $value; } } - $sql .= ' ' . $override . 'VALUES (' . implode(',', $values) . ')'; + $sql .= ' ' . $override . 'VALUES (' . implode(',', $values) . ')' . $conflictClause; $this->getConnection()->execute($sql, $vals); } } @@ -1196,7 +1199,7 @@ public function insert(TableMetadata $table, array $row): void /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows): void + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void { $sql = sprintf( 'INSERT INTO %s ', @@ -1213,11 +1216,13 @@ public function bulkinsert(TableMetadata $table, array $rows): void $sql .= '(' . implode(', ', array_map($this->quoteColumnName(...), $keys)) . ') ' . $override . 'VALUES '; + $conflictClause = $this->getConflictClause($mode); + if ($this->isDryRunEnabled()) { $values = array_map(function ($row) { return '(' . implode(', ', array_map($this->quoteValue(...), $row)) . ')'; }, $rows); - $sql .= implode(', ', $values) . ';'; + $sql .= implode(', ', $values) . $conflictClause . ';'; $this->io->out($sql); } else { $vals = []; @@ -1245,11 +1250,26 @@ public function bulkinsert(TableMetadata $table, array $rows): void $query = '(' . implode(', ', $values) . ')'; $queries[] = $query; } - $sql .= implode(',', $queries); + $sql .= implode(',', $queries) . $conflictClause; $this->getConnection()->execute($sql, $vals); } } + /** + * Get the ON CONFLICT clause based on insert mode. + * + * @param \Migrations\Db\InsertMode|null $mode Insert mode + * @return string + */ + protected function getConflictClause(?InsertMode $mode = null): string + { + if ($mode === InsertMode::IGNORE) { + return ' ON CONFLICT DO NOTHING'; + } + + return ''; + } + /** * Get the adapter type name * diff --git a/src/Db/Adapter/SqliteAdapter.php b/src/Db/Adapter/SqliteAdapter.php index 06bdd841d..91847376f 100644 --- a/src/Db/Adapter/SqliteAdapter.php +++ b/src/Db/Adapter/SqliteAdapter.php @@ -14,6 +14,7 @@ use InvalidArgumentException; use Migrations\Db\AlterInstructions; use Migrations\Db\Expression; +use Migrations\Db\InsertMode; use Migrations\Db\Literal; use Migrations\Db\Table\CheckConstraint; use Migrations\Db\Table\Column; @@ -1686,4 +1687,16 @@ protected function getForeignKeySqlDefinition(ForeignKey $foreignKey): string return $def; } + + /** + * @inheritDoc + */ + protected function getInsertPrefix(?InsertMode $mode = null): string + { + if ($mode === InsertMode::IGNORE) { + return 'INSERT OR IGNORE'; + } + + return 'INSERT'; + } } diff --git a/src/Db/Adapter/SqlserverAdapter.php b/src/Db/Adapter/SqlserverAdapter.php index 7faa6761f..3d62c2a77 100644 --- a/src/Db/Adapter/SqlserverAdapter.php +++ b/src/Db/Adapter/SqlserverAdapter.php @@ -14,6 +14,7 @@ use Cake\I18n\DateTime; use InvalidArgumentException; use Migrations\Db\AlterInstructions; +use Migrations\Db\InsertMode; use Migrations\Db\Literal; use Migrations\Db\Table\CheckConstraint; use Migrations\Db\Table\Column; @@ -999,9 +1000,9 @@ public function migrated(MigrationInterface $migration, string $direction, strin /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row): void + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void { - $sql = $this->generateInsertSql($table, $row); + $sql = $this->generateInsertSql($table, $row, $mode); $sql = $this->updateSQLForIdentityInsert($table->getName(), $sql); @@ -1025,9 +1026,9 @@ public function insert(TableMetadata $table, array $row): void /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows): void + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void { - $sql = $this->generateBulkInsertSql($table, $rows); + $sql = $this->generateBulkInsertSql($table, $rows, $mode); $sql = $this->updateSQLForIdentityInsert($table->getName(), $sql); @@ -1105,4 +1106,16 @@ protected function getDropCheckConstraintInstructions(string $tableName, string { throw new BadMethodCallException('Check constraints are not yet implemented for SQL Server adapter'); } + + /** + * @inheritDoc + */ + protected function getInsertPrefix(?InsertMode $mode = null): string + { + if ($mode === InsertMode::IGNORE) { + throw new BadMethodCallException('INSERT IGNORE is not supported for SQL Server'); + } + + return parent::getInsertPrefix($mode); + } } diff --git a/src/Db/Adapter/TimedOutputAdapter.php b/src/Db/Adapter/TimedOutputAdapter.php index 5868a5b98..b356403da 100644 --- a/src/Db/Adapter/TimedOutputAdapter.php +++ b/src/Db/Adapter/TimedOutputAdapter.php @@ -10,6 +10,7 @@ use BadMethodCallException; use Cake\Console\ConsoleIo; +use Migrations\Db\InsertMode; use Migrations\Db\Table\Column; use Migrations\Db\Table\ForeignKey; use Migrations\Db\Table\Index; @@ -83,22 +84,22 @@ function ($value) { /** * @inheritDoc */ - public function insert(TableMetadata $table, array $row): void + public function insert(TableMetadata $table, array $row, ?InsertMode $mode = null): void { $end = $this->startCommandTimer(); $this->writeCommand('insert', [$table->getName()]); - parent::insert($table, $row); + parent::insert($table, $row, $mode); $end(); } /** * @inheritDoc */ - public function bulkinsert(TableMetadata $table, array $rows): void + public function bulkinsert(TableMetadata $table, array $rows, ?InsertMode $mode = null): void { $end = $this->startCommandTimer(); $this->writeCommand('bulkinsert', [$table->getName()]); - parent::bulkinsert($table, $rows); + parent::bulkinsert($table, $rows, $mode); $end(); } diff --git a/src/Db/InsertMode.php b/src/Db/InsertMode.php new file mode 100644 index 000000000..6a77eeffb --- /dev/null +++ b/src/Db/InsertMode.php @@ -0,0 +1,31 @@ + $data Data * @return $this */ public function setData(array $data) @@ -624,6 +631,21 @@ public function insert(array $data) return $this; } + /** + * Insert data into the table, skipping rows that would cause duplicate key conflicts. + * + * This method is idempotent and safe to run multiple times. + * + * @param array $data array of data in the same format as insert() + * @return $this + */ + public function insertOrSkip(array $data) + { + $this->insertMode = InsertMode::IGNORE; + + return $this->insert($data); + } + /** * Creates a table from the object instance. * @@ -743,14 +765,15 @@ public function saveData(): void } if ($bulk) { - $this->getAdapter()->bulkinsert($this->table, $this->getData()); + $this->getAdapter()->bulkinsert($this->table, $this->getData(), $this->insertMode); } else { foreach ($this->getData() as $row) { - $this->getAdapter()->insert($this->table, $row); + $this->getAdapter()->insert($this->table, $row, $this->insertMode); } } $this->resetData(); + $this->insertMode = null; } /** diff --git a/src/SeedInterface.php b/src/SeedInterface.php index 356fa3307..1c9b29da4 100644 --- a/src/SeedInterface.php +++ b/src/SeedInterface.php @@ -142,6 +142,19 @@ public function fetchAll(string $sql): array; */ public function insert(string $tableName, array $data): void; + /** + * Insert data into a table, skipping rows that would cause duplicate key conflicts. + * + * This method is idempotent and safe to run multiple times. + * Uses INSERT IGNORE (MySQL), ON CONFLICT DO NOTHING (PostgreSQL), + * or INSERT OR IGNORE (SQLite). + * + * @param string $tableName Table name + * @param array $data Data + * @return void + */ + public function insertOrSkip(string $tableName, array $data): void; + /** * Checks to see if a table exists. * diff --git a/src/View/Helper/MigrationHelper.php b/src/View/Helper/MigrationHelper.php index 0ab2b4f44..42b3dbfac 100644 --- a/src/View/Helper/MigrationHelper.php +++ b/src/View/Helper/MigrationHelper.php @@ -647,7 +647,7 @@ public function resetTableStatementGenerationFor(string $table): void * Render an element. * * @param string $name The name of the element to render. - * @param array $data Additional data for the element. + * @param array $data Additional data for the element. * @return ?string */ public function element(string $name, array $data): ?string diff --git a/tests/TestCase/Db/Adapter/MysqlAdapterTest.php b/tests/TestCase/Db/Adapter/MysqlAdapterTest.php index 67abf8967..3e97d8163 100644 --- a/tests/TestCase/Db/Adapter/MysqlAdapterTest.php +++ b/tests/TestCase/Db/Adapter/MysqlAdapterTest.php @@ -2446,4 +2446,90 @@ public function testDecimalWithScaleZero() 'CREATE TABLE should contain DECIMAL(65,0) with scale=0 properly defined', ); } + + public function testInsertOrSkipWithDuplicates() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Duplicate - should be skipped + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM users'); + $this->assertCount(1, $rows); + $this->assertEquals('John', $rows[0]['name']); + } + + public function testInsertModeResetsAfterInsertOrSkip() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert with insertOrSkip + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + } + + public function testBulkinsertOrSkipWithDuplicates() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First bulk insert + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 10.50], + ['sku' => 'DEF456', 'price' => 20.00], + ])->save(); + + // Mix of new and duplicate - duplicates should be skipped + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 99.99], // Duplicate + ['sku' => 'GHI789', 'price' => 30.00], // New + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products ORDER BY sku'); + $this->assertCount(3, $rows); + $this->assertEquals('10.50', $rows[0]['price']); // Original price preserved + $this->assertEquals('20.00', $rows[1]['price']); + $this->assertEquals('30.00', $rows[2]['price']); + } + + public function testInsertOrSkipWithoutDuplicates() + { + $table = new Table('categories', [], $this->adapter); + $table->addColumn('name', 'string') + ->create(); + + // Should work like normal insert + $table->insertOrSkip([ + ['name' => 'Category 1'], + ['name' => 'Category 2'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM categories'); + $this->assertCount(2, $rows); + } } diff --git a/tests/TestCase/Db/Adapter/PostgresAdapterTest.php b/tests/TestCase/Db/Adapter/PostgresAdapterTest.php index 758970302..547045b81 100644 --- a/tests/TestCase/Db/Adapter/PostgresAdapterTest.php +++ b/tests/TestCase/Db/Adapter/PostgresAdapterTest.php @@ -2819,4 +2819,90 @@ public function testCheckConstraintWithComplexExpression() $this->expectException(PDOException::class); $this->adapter->execute("INSERT INTO {$quotedTableName} (email, status) VALUES ('test@example.com', 'invalid')"); } + + public function testInsertOrSkipWithDuplicates() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Duplicate - should be skipped + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM users'); + $this->assertCount(1, $rows); + $this->assertEquals('John', $rows[0]['name']); + } + + public function testInsertModeResetsAfterInsertOrSkip() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert with insertOrSkip + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + } + + public function testBulkinsertOrSkipWithDuplicates() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First bulk insert + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 10.50], + ['sku' => 'DEF456', 'price' => 20.00], + ])->save(); + + // Mix of new and duplicate - duplicates should be skipped + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 99.99], // Duplicate + ['sku' => 'GHI789', 'price' => 30.00], // New + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products ORDER BY sku'); + $this->assertCount(3, $rows); + $this->assertEquals('10.50', $rows[0]['price']); // Original price preserved + $this->assertEquals('20.00', $rows[1]['price']); + $this->assertEquals('30.00', $rows[2]['price']); + } + + public function testInsertOrSkipWithoutDuplicates() + { + $table = new Table('categories', [], $this->adapter); + $table->addColumn('name', 'string') + ->create(); + + // Should work like normal insert + $table->insertOrSkip([ + ['name' => 'Category 1'], + ['name' => 'Category 2'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM categories'); + $this->assertCount(2, $rows); + } } diff --git a/tests/TestCase/Db/Adapter/SqliteAdapterTest.php b/tests/TestCase/Db/Adapter/SqliteAdapterTest.php index e3d70afd6..2384b41a1 100644 --- a/tests/TestCase/Db/Adapter/SqliteAdapterTest.php +++ b/tests/TestCase/Db/Adapter/SqliteAdapterTest.php @@ -3148,4 +3148,90 @@ public function testCheckConstraintWithComplexExpression() $this->expectException(PDOException::class); $this->adapter->execute("INSERT INTO {$quotedTableName} (email, status) VALUES ('test@example.com', 'invalid')"); } + + public function testInsertOrSkipWithDuplicates() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Duplicate - should be skipped + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM users'); + $this->assertCount(1, $rows); + $this->assertEquals('John', $rows[0]['name']); + } + + public function testInsertModeResetsAfterInsertOrSkip() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->addIndex('email', ['unique' => true]) + ->create(); + + // First insert with insertOrSkip + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + + // Now use regular insert with duplicate - should throw exception + $this->expectException(PDOException::class); + $table->insert([ + ['email' => 'test@example.com', 'name' => 'Jane'], + ])->save(); + } + + public function testBulkinsertOrSkipWithDuplicates() + { + $table = new Table('products', [], $this->adapter); + $table->addColumn('sku', 'string', ['limit' => 50]) + ->addColumn('price', 'decimal', ['precision' => 10, 'scale' => 2]) + ->addIndex('sku', ['unique' => true]) + ->create(); + + // First bulk insert + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 10.50], + ['sku' => 'DEF456', 'price' => 20.00], + ])->save(); + + // Mix of new and duplicate - duplicates should be skipped + $table->insertOrSkip([ + ['sku' => 'ABC123', 'price' => 99.99], // Duplicate + ['sku' => 'GHI789', 'price' => 30.00], // New + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM products ORDER BY sku'); + $this->assertCount(3, $rows); + $this->assertEquals('10.50', $rows[0]['price']); // Original price preserved + $this->assertEquals('20.00', $rows[1]['price']); + $this->assertEquals('30.00', $rows[2]['price']); + } + + public function testInsertOrSkipWithoutDuplicates() + { + $table = new Table('categories', [], $this->adapter); + $table->addColumn('name', 'string') + ->create(); + + // Should work like normal insert + $table->insertOrSkip([ + ['name' => 'Category 1'], + ['name' => 'Category 2'], + ])->save(); + + $rows = $this->adapter->fetchAll('SELECT * FROM categories'); + $this->assertCount(2, $rows); + } } diff --git a/tests/TestCase/Db/Adapter/SqlserverAdapterTest.php b/tests/TestCase/Db/Adapter/SqlserverAdapterTest.php index e2abbe06e..396665dcc 100644 --- a/tests/TestCase/Db/Adapter/SqlserverAdapterTest.php +++ b/tests/TestCase/Db/Adapter/SqlserverAdapterTest.php @@ -1499,4 +1499,19 @@ public function testIdentityInsert() $this->assertEquals(20, $res[0]['id']); $this->assertEquals(50, $res[1]['id']); } + + public function testInsertOrSkipThrowsException() + { + $table = new Table('users', [], $this->adapter); + $table->addColumn('email', 'string', ['limit' => 255]) + ->addColumn('name', 'string') + ->create(); + + $this->expectException(BadMethodCallException::class); + $this->expectExceptionMessage('INSERT IGNORE is not supported for SQL Server'); + + $table->insertOrSkip([ + ['email' => 'test@example.com', 'name' => 'John'], + ])->save(); + } }