Skip to content

Commit 017e8ed

Browse files
committed
Added documentation and change log
1 parent d9ac9a7 commit 017e8ed

File tree

9 files changed

+246
-7
lines changed

9 files changed

+246
-7
lines changed

system/Database/BaseBuilder.php

Lines changed: 1 addition & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -1847,7 +1847,7 @@ public function setBatch($key, string $value = '', ?bool $escape = null)
18471847
*
18481848
* @return bool|string
18491849
*/
1850-
public function getCompiledUpsert(bool $reset = true)
1850+
public function getCompiledUpsert()
18511851
{
18521852
$currentTestMode = $this->testMode;
18531853

@@ -1857,11 +1857,6 @@ public function getCompiledUpsert(bool $reset = true)
18571857

18581858
$this->testMode = $currentTestMode;
18591859

1860-
// this doesn't work with current implimentation - is cleared in upsert method
1861-
if ($reset === true) {
1862-
$this->resetWrite();
1863-
}
1864-
18651860
return $this->compileFinalQuery($sql);
18661861
}
18671862

user_guide_src/source/changelogs/v4.3.0.rst

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -41,6 +41,7 @@ Enhancements
4141
- SQLite ``BaseConnection::getIndexData()`` now can return pseudo index named ``PRIMARY`` for `AUTOINCREMENT` column, and each returned index data has ``type`` property.
4242
- Added ``spark filter:check`` command to check the filters for a route. See :ref:`Controller Filters <spark-filter-check>` for the details.
4343
- Now **Encryption** can decrypt data encrypted with CI3's Encryption. See :ref:`encryption-compatible-with-ci3`.
44+
- Added ``upsert()`` and ``upsertBatch()`` methods to builder. Also included for use with upserts are ``onConstraint()`` and ``updateFields()`` methods.
4445

4546
Changes
4647
*******

user_guide_src/source/database/query_builder.rst

Lines changed: 137 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -851,6 +851,82 @@ The first parameter is an associative array of values.
851851

852852
.. note:: All values are escaped automatically producing safer queries.
853853

854+
**************
855+
Upserting Data
856+
**************
857+
858+
Upsert
859+
======
860+
861+
$builder->upsert()
862+
------------------
863+
864+
Generates an upsert string based on the data you supply, and runs the
865+
query. You can either pass an **array** or an **object** to the
866+
method. By default a constraint will be defined in order. A primary
867+
key will be selected first and then unique keys. Mysql will use any
868+
constraint by default. Here is an example using an array:
869+
870+
.. literalinclude:: query_builder/105.php
871+
872+
The first parameter is an associative array of values.
873+
874+
Here is an example using an object:
875+
876+
.. literalinclude:: query_builder/106.php
877+
878+
The first parameter is an object.
879+
880+
.. note:: All values are escaped automatically producing safer queries.
881+
882+
$builder->getCompiledUpsert()
883+
-----------------------------
884+
885+
Compiles the upsert query just like ``$builder->upsert()`` but does not
886+
*run* the query. This method simply returns the SQL query as a string.
887+
888+
Example:
889+
890+
.. literalinclude:: query_builder/107.php
891+
892+
.. note:: This method doesn't work for batch upserts.
893+
894+
upsertBatch
895+
===========
896+
897+
$builder->upsertBatch()
898+
-----------------------
899+
900+
Generates an upsert string based on the data you supply, and runs the
901+
query. You can either pass an **array** or an **object** to the
902+
method. By default a constraint will be defined in order. A primary
903+
key will be selected first and then unique keys. Mysql will use any
904+
constraint by default. Here is an example using an array:
905+
906+
.. literalinclude:: query_builder/108.php
907+
908+
The first parameter is an associative array of values.
909+
910+
.. note:: All values are escaped automatically producing safer queries.
911+
912+
$builder->onConstraint()
913+
------------------------
914+
915+
Allows manually setting constraint to be used for upsert. This does
916+
not work with MySQL because MySQL checks all constraints by default.
917+
918+
.. literalinclude:: query_builder/109.php
919+
920+
This method accepts a string or an array of columns.
921+
922+
$builder->updateFields()
923+
------------------------
924+
Allows manually setting the fields to be updated when performing upserts.
925+
926+
.. literalinclude:: query_builder/110.php
927+
928+
This method accepts a string or an array of columns.
929+
854930
*************
855931
Updating Data
856932
*************
@@ -1555,7 +1631,7 @@ Class Reference
15551631
:returns: ``BaseBuilder`` instance (method chaining)
15561632
:rtype: ``BaseBuilder``
15571633

1558-
Adds field/value pairs to be passed later to ``insert()``, ``update()`` or ``replace()``.
1634+
Adds field/value pairs to be passed later to ``insert()``, ``upsert()``, ``update()`` or ``replace()``.
15591635

15601636
.. php:method:: insert([$set = null[, $escape = null]])
15611637
@@ -1590,6 +1666,59 @@ Class Reference
15901666

15911667
Adds field/value pairs to be inserted in a table later via ``insertBatch()``.
15921668

1669+
.. php:method:: upsert([$set = null[, $escape = null]])
1670+
1671+
:param array $set: An associative array of field/value pairs
1672+
:param bool $escape: Whether to escape values
1673+
:returns: ``true`` on success, ``false`` on failure
1674+
:rtype: bool
1675+
1676+
Compiles and executes an ``UPSERT`` statement.
1677+
1678+
.. php:method:: upsertBatch([$set = null[, $escape = null[, $batch_size = 100]]])
1679+
1680+
:param array $set: Data to upsert
1681+
:param bool $escape: Whether to escape values
1682+
:param int $batch_size: Count of rows to upsert at once
1683+
:returns: Number of rows upserted or ``false`` on failure
1684+
:rtype: int|false
1685+
1686+
Compiles and executes batch ``UPSERT`` statements.
1687+
1688+
.. note:: MySQL uses ``ON DUPLICATE KEY UPDATE``, the affected-rows value
1689+
per row is 1 if the row is inserted as a new row, 2 if an existing row
1690+
is updated, and 0 if an existing row is set to its current values.
1691+
1692+
.. note:: When more than ``$batch_size`` rows are provided, multiple
1693+
``UPSERT`` queries will be executed, each trying to upsert
1694+
up to ``$batch_size`` rows.
1695+
1696+
.. php:method:: setBatch($key[, $value = ''[, $escape = null]])
1697+
1698+
:param mixed $key: Field name or an array of field/value pairs
1699+
:param string $value: Field value, if $key is a single field
1700+
:param bool $escape: Whether to escape values
1701+
:returns: ``BaseBuilder`` instance (method chaining)
1702+
:rtype: ``BaseBuilder``
1703+
1704+
Adds field/value pairs to be upserted in a table later via ``upsertBatch()``.
1705+
1706+
.. php:method:: onConstraint($keys)
1707+
1708+
:param array|string $keys: List of columns used as constraints
1709+
:returns: ``BaseBuilder`` instance (method chaining)
1710+
:rtype: ``BaseBuilder``
1711+
1712+
Defines fields used as constraints for ``upsert()`` and ``upsertBatch()``.
1713+
1714+
.. php:method:: updateFields($keys)
1715+
1716+
:param array|string $keys: List of fields to be updated
1717+
:returns: ``BaseBuilder`` instance (method chaining)
1718+
:rtype: ``BaseBuilder``
1719+
1720+
Defines fields to be updated for ``upsert()`` and ``upsertBatch()``.
1721+
15931722
.. php:method:: update([$set = null[, $where = null[, $limit = null]]])
15941723
15951724
:param array $set: An associative array of field/value pairs
@@ -1693,6 +1822,13 @@ Class Reference
16931822

16941823
Compiles an ``INSERT`` statement and returns it as a string.
16951824

1825+
.. php:method:: getCompiledUpsert()
1826+
1827+
:returns: The compiled SQL statement as a string
1828+
:rtype: string
1829+
1830+
Compiles an ``UPSERT`` statement and returns it as a string.
1831+
16961832
.. php:method:: getCompiledUpdate([$reset = true])
16971833
16981834
:param bool $reset: Whether to reset the current QB values or not
Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,14 @@
1+
<?php
2+
3+
$data = [
4+
'email' => '[email protected]',
5+
'name' => 'Ahmadinejad',
6+
'country' => 'Iran',
7+
];
8+
9+
$builder->upsert($data);
10+
// MySQLi produces: INSERT INTO.. ON DUPLICATE KEY UPDATE..
11+
// Postgre produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
12+
// SQLite3 produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
13+
// SQLSRV produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
14+
// OCI8 produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
<?php
2+
3+
class Myclass
4+
{
5+
public $email = '[email protected]';
6+
public $name = 'Ahmadinejad';
7+
public $country = 'Iran';
8+
}
9+
10+
$object = new Myclass();
11+
$builder->upsert($object);
Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
<?php
2+
3+
$data = [
4+
'email' => '[email protected]',
5+
'name' => 'Ahmadinejad',
6+
'country' => 'Iran',
7+
];
8+
9+
$sql = $builder->set($data)->getCompiledUpsert();
10+
echo $sql;
11+
/* MySQLi produces:
12+
INSERT INTO `db_user` (`country`, `email`, `name`)
13+
VALUES ('Iran','[email protected]','Ahmadinejad')
14+
ON DUPLICATE KEY UPDATE
15+
`country` = VALUES(`country`),
16+
`email` = VALUES(`email`),
17+
`name` = VALUES(`name`)
18+
*/
Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,23 @@
1+
<?php
2+
3+
$data = [
4+
[
5+
'id' => 2,
6+
'email' => '[email protected]',
7+
'name' => 'Ahmadinejad',
8+
'country' => 'Iran',
9+
],
10+
[
11+
'id' => null,
12+
'email' => '[email protected]',
13+
'name' => 'Pedro',
14+
'country' => 'El Salvador',
15+
],
16+
];
17+
18+
$builder->insertBatch($data);
19+
// MySQLi produces: INSERT INTO.. ON DUPLICATE KEY UPDATE..
20+
// Postgre produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
21+
// SQLite3 produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
22+
// SQLSRV produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
23+
// OCI8 produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
<?php
2+
3+
$data = [
4+
'id' => 2,
5+
'email' => '[email protected]',
6+
'name' => 'Ahmadinejad',
7+
'country' => 'Iran',
8+
];
9+
10+
$builder->onConstraint('email')->upsert($data);
11+
/* Postgre produces:
12+
INSERT INTO "db_user"("country", "email", "id", "name")
13+
VALUES ('Iran','[email protected]',2,'Ahmadinejad')
14+
ON CONFLICT("email")
15+
DO UPDATE SET
16+
"country" = "excluded"."country",
17+
"id" = "excluded"."id",
18+
"name" = "excluded"."name"
19+
*/
Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
<?php
2+
3+
$data = [
4+
'id' => 2,
5+
'email' => '[email protected]',
6+
'name' => 'Ahmadinejad Zaghari',
7+
'country' => 'Afghanistan',
8+
];
9+
10+
$builder->updateFields('name, country')->upsert($data);
11+
/* SQLSRV produces:
12+
MERGE INTO "test"."dbo"."db_user"
13+
USING (
14+
VALUES ('Iran','[email protected]',2,'Ahmadinejad')
15+
) "_upsert" ("country", "email", "id", "name")
16+
ON ( 1 != 1 OR ("test"."dbo"."db_user"."id" = "_upsert"."id"))
17+
WHEN MATCHED THEN UPDATE SET
18+
"country" = "_upsert"."country",
19+
"name" = "_upsert"."name"
20+
WHEN NOT MATCHED THEN INSERT ("country", "email", "id", "name")
21+
VALUES ("_upsert"."country", "_upsert"."email", "_upsert"."id", "_upsert"."name");
22+
*/

0 commit comments

Comments
 (0)