diff --git a/system/Database/BaseBuilder.php b/system/Database/BaseBuilder.php index 2fbfd9656532..43227ee1a764 100644 --- a/system/Database/BaseBuilder.php +++ b/system/Database/BaseBuilder.php @@ -168,6 +168,15 @@ class BaseBuilder */ protected $QBWhereGroupCount = 0; + /** + * Ignore data that cause certain + * exceptions, for example in case of + * duplicate keys. + * + * @var boolean + */ + protected $QBIgnore = false; + /** * A reference to the database connection. * @@ -220,6 +229,14 @@ class BaseBuilder */ protected $canLimitWhereUpdates = true; + /** + * Specifies which sql statements + * support the ignore option. + * + * @var array + */ + protected $supportedIgnoreStatements = []; + /** * Builder testing mode status. * @@ -291,6 +308,25 @@ public function getBinds(): array //-------------------------------------------------------------------- + /** + * Ignore + * + * Set ignore Flag for next insert, + * update or delete query. + * + * @param boolean $ignore + * + * @return BaseBuilder + */ + public function ignore(bool $ignore = true) + { + $this->QBIgnore = $ignore; + + return $this; + } + + //-------------------------------------------------------------------- + /** * Select * @@ -2037,7 +2073,7 @@ public function insertBatch(array $set = null, bool $escape = null, int $batchSi */ protected function _insertBatch(string $table, array $keys, array $values): string { - return 'INSERT INTO ' . $table . ' (' . implode(', ', $keys) . ') VALUES ' . implode(', ', $values); + return 'INSERT ' . $this->compileIgnore('insert') . 'INTO ' . $table . ' (' . implode(', ', $keys) . ') VALUES ' . implode(', ', $values); } //-------------------------------------------------------------------- @@ -2106,6 +2142,8 @@ public function setInsertBatch($key, string $value = '', bool $escape = null) * * @param boolean $reset TRUE: reset QB values; FALSE: leave QB values alone * + * @throws DatabaseException + * * @return string */ public function getCompiledInsert(bool $reset = true): string @@ -2139,6 +2177,8 @@ public function getCompiledInsert(bool $reset = true): string * @param array $set An associative array of insert values * @param boolean $escape Whether to escape values and identifiers * + * @throws DatabaseException + * * @return BaseResult|Query|false */ public function insert(array $set = null, bool $escape = null) @@ -2216,7 +2256,7 @@ protected function validateInsert(): bool */ protected function _insert(string $table, array $keys, array $unescapedKeys): string { - return 'INSERT INTO ' . $table . ' (' . implode(', ', $keys) . ') VALUES (' . implode(', ', $unescapedKeys) . ')'; + return 'INSERT ' . $this->compileIgnore('insert') . 'INTO ' . $table . ' (' . implode(', ', $keys) . ') VALUES (' . implode(', ', $unescapedKeys) . ')'; } //-------------------------------------------------------------------- @@ -2330,6 +2370,8 @@ public function getCompiledUpdate(bool $reset = true): string * @param mixed $where * @param integer $limit * + * @throws DatabaseException + * * @return boolean TRUE on success, FALSE on failure */ public function update(array $set = null, $where = null, int $limit = null): bool @@ -2393,14 +2435,14 @@ public function update(array $set = null, $where = null, int $limit = null): boo */ protected function _update(string $table, array $values): string { - $valstr = []; + $valStr = []; foreach ($values as $key => $val) { - $valstr[] = $key . ' = ' . $val; + $valStr[] = $key . ' = ' . $val; } - return 'UPDATE ' . $table . ' SET ' . implode(', ', $valstr) + return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . implode(', ', $valStr) . $this->compileWhereHaving('QBWhere') . $this->compileOrderBy() . ($this->QBLimit ? $this->_limit(' ') : ''); @@ -2530,6 +2572,7 @@ protected function _updateBatch(string $table, array $values, string $index): st { $ids = []; $final = []; + foreach ($values as $key => $val) { $ids[] = $val[$index]; @@ -2553,7 +2596,7 @@ protected function _updateBatch(string $table, array $values, string $index): st $this->where($index . ' IN(' . implode(',', $ids) . ')', null, false); - return 'UPDATE ' . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); + return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . substr($cases, 0, -2) . $this->compileWhereHaving('QBWhere'); } //-------------------------------------------------------------------- @@ -2806,7 +2849,7 @@ public function decrement(string $column, int $value = 1) */ protected function _delete(string $table): string { - return 'DELETE FROM ' . $table . $this->compileWhereHaving('QBWhere') + return 'DELETE ' . $this->compileIgnore('delete') . 'FROM ' . $table . $this->compileWhereHaving('QBWhere') . ($this->QBLimit ? ' LIMIT ' . $this->QBLimit : ''); } @@ -2922,6 +2965,32 @@ protected function compileSelect($select_override = false): string //-------------------------------------------------------------------- + /** + * Compile Ignore Statement + * + * Checks if the ignore option is supported by + * the Database Driver for the specific statement. + * + * @param string $statement + * + * @return string + */ + protected function compileIgnore(string $statement) + { + $sql = ''; + + if ($this->QBIgnore && + isset($this->supportedIgnoreStatements[$statement]) + ) + { + $sql = trim($this->supportedIgnoreStatements[$statement]) . ' '; + } + + return $sql; + } + + //-------------------------------------------------------------------- + /** * Compile WHERE, HAVING statements * @@ -3242,6 +3311,7 @@ protected function resetWrite() 'QBOrderBy' => [], 'QBKeys' => [], 'QBLimit' => false, + 'QBIgnore' => false, ]); } diff --git a/system/Database/MySQLi/Builder.php b/system/Database/MySQLi/Builder.php index 908f571a4924..5fd8acbdafa5 100644 --- a/system/Database/MySQLi/Builder.php +++ b/system/Database/MySQLi/Builder.php @@ -54,6 +54,18 @@ class Builder extends BaseBuilder */ protected $escapeChar = '`'; + /** + * Specifies which sql statements + * support the ignore option. + * + * @var array + */ + protected $supportedIgnoreStatements = [ + 'update' => 'IGNORE', + 'insert' => 'IGNORE', + 'delete' => 'IGNORE', + ]; + /** * FROM tables * @@ -73,5 +85,4 @@ protected function _fromTables(): string return implode(', ', $this->QBFrom); } - } diff --git a/system/Database/Postgre/Builder.php b/system/Database/Postgre/Builder.php index a7424b026b87..f375445add19 100644 --- a/system/Database/Postgre/Builder.php +++ b/system/Database/Postgre/Builder.php @@ -40,6 +40,7 @@ use CodeIgniter\Database\BaseBuilder; use CodeIgniter\Database\Exceptions\DatabaseException; +use http\Encoding\Stream\Inflate; /** * Builder for Postgre @@ -56,6 +57,40 @@ class Builder extends BaseBuilder 'RANDOM()', ]; + /** + * Specifies which sql statements + * support the ignore option. + * + * @var array + */ + protected $supportedIgnoreStatements = [ + 'insert' => 'ON CONFLICT DO NOTHING', + ]; + + //-------------------------------------------------------------------- + + /** + * Compile Ignore Statement + * + * Checks if the ignore option is supported by + * the Database Driver for the specific statement. + * + * @param string $statement + * + * @return string + */ + protected function compileIgnore(string $statement) + { + $sql = parent::compileIgnore($statement); + + if (! empty($sql)) + { + $sql = ' ' . trim($sql); + } + + return $sql; + } + //-------------------------------------------------------------------- /** @@ -98,6 +133,8 @@ public function orderBy(string $orderBy, string $direction = '', bool $escape = * @param string $column * @param integer $value * + * @throws DatabaseException + * * @return mixed */ public function increment(string $column, int $value = 1) @@ -117,6 +154,8 @@ public function increment(string $column, int $value = 1) * @param string $column * @param integer $value * + * @throws DatabaseException + * * @return mixed */ public function decrement(string $column, int $value = 1) diff --git a/system/Database/SQLite3/Builder.php b/system/Database/SQLite3/Builder.php index 911b9fe68c67..3c94cea1fab1 100644 --- a/system/Database/SQLite3/Builder.php +++ b/system/Database/SQLite3/Builder.php @@ -70,6 +70,13 @@ class Builder extends BaseBuilder */ protected $canLimitWhereUpdates = false; + /** + * @var array + */ + protected $supportedIgnoreStatements = [ + 'insert' => 'OR IGNORE', + ]; + //-------------------------------------------------------------------- /** @@ -106,6 +113,4 @@ protected function _truncate(string $table): string return 'DELETE FROM ' . $table; } - //-------------------------------------------------------------------- - } diff --git a/tests/system/Database/Builder/DeleteTest.php b/tests/system/Database/Builder/DeleteTest.php index cd4708943da2..c2cc7e6a53a0 100644 --- a/tests/system/Database/Builder/DeleteTest.php +++ b/tests/system/Database/Builder/DeleteTest.php @@ -35,5 +35,4 @@ public function testDelete() $this->assertEquals($expectedBinds, $builder->getBinds()); } - //-------------------------------------------------------------------- } diff --git a/user_guide_src/source/database/query_builder.rst b/user_guide_src/source/database/query_builder.rst index cebdf60655fe..2050af4d7ef8 100755 --- a/user_guide_src/source/database/query_builder.rst +++ b/user_guide_src/source/database/query_builder.rst @@ -860,6 +860,22 @@ The first parameter is an object. .. note:: All values are escaped automatically producing safer queries. +**$builder->ignore()** + +Generates an insert ignore string based on the data you supply, and runs the +query. So if an entry with the same primary key already exists, the query won't be inserted. +You can optionally pass an **boolean** to the function. Here is an example using the array of the above example:: + + $data = [ + 'title' => 'My title', + 'name' => 'My Name', + 'date' => 'My date' + ]; + + $builder->ignore(true)->insert($data); + // Produces: INSERT OR IGNORE INTO mytable (title, name, date) VALUES ('My title', 'My name', 'My date') + + **$builder->getCompiledInsert()** Compiles the insertion query just like $builder->insert() but does not