Skip to content

Commit 32d350c

Browse files
committed
Add documentation and change log for upsert
1 parent 7d8b798 commit 32d350c

File tree

6 files changed

+203
-0
lines changed

6 files changed

+203
-0
lines changed

user_guide_src/source/changelogs/v4.3.0.rst

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -127,6 +127,7 @@ Database
127127
- Improved data returned by :ref:`BaseConnection::getForeignKeyData() <metadata-getforeignkeydata>`. All DBMS returns the same structure.
128128
- :php:meth:`CodeIgniter\\Database\\Forge::addForeignKey()` now includes a name parameter to manual set foreign key names. Not supported in SQLite3.
129129
- Added ``when()`` and ``whenNot()`` methods to conditionally add clauses to the query. See :ref:`BaseBuilder::when() <db-builder-when>` for details.
130+
- Added ``upsert()`` and ``upsertBatch()`` methods to QueryBuilder. See :ref:`upsert-data`.
130131

131132
Model
132133
=====

user_guide_src/source/database/query_builder.rst

Lines changed: 109 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -876,6 +876,90 @@ The first parameter is an associative array of values.
876876

877877
.. warning:: When you use ``RawSql``, you MUST escape the data manually. Failure to do so could result in SQL injections.
878878

879+
.. _upsert-data:
880+
881+
**************
882+
Upserting Data
883+
**************
884+
885+
Upsert
886+
======
887+
888+
$builder->upsert()
889+
------------------
890+
891+
Generates an upsert string based on the data you supply, and runs the
892+
query. You can either pass an **array** or an **object** to the
893+
method. By default a constraint will be defined in order. A primary
894+
key will be selected first and then unique keys. MySQL will use any
895+
constraint by default. Here is an example using an array:
896+
897+
.. literalinclude:: query_builder/112.php
898+
899+
The first parameter is an associative array of values.
900+
901+
Here is an example using an object:
902+
903+
.. literalinclude:: query_builder/113.php
904+
905+
The first parameter is an object.
906+
907+
.. note:: All values are escaped automatically producing safer queries.
908+
909+
$builder->getCompiledUpsert()
910+
-----------------------------
911+
912+
Compiles the upsert query just like ``$builder->upsert()`` but does not
913+
*run* the query. This method simply returns the SQL query as a string.
914+
915+
Example:
916+
917+
.. literalinclude:: query_builder/114.php
918+
919+
.. note:: This method doesn't work for batch upserts.
920+
921+
upsertBatch
922+
===========
923+
924+
$builder->upsertBatch()
925+
-----------------------
926+
927+
Generates an upsert string based on the data you supply, and runs the
928+
query. You can either pass an **array** or an **object** to the
929+
method. By default a constraint will be defined in order. A primary
930+
key will be selected first and then unique keys. Mysql will use any
931+
constraint by default. Here is an example using an array:
932+
933+
.. literalinclude:: query_builder/108.php
934+
935+
The first parameter is an associative array of values.
936+
937+
.. note:: All values are escaped automatically producing safer queries.
938+
939+
$builder->onConstraint()
940+
------------------------
941+
942+
Allows manually setting constraint to be used for upsert. This does
943+
not work with MySQL because MySQL checks all constraints by default.
944+
945+
.. literalinclude:: query_builder/109.php
946+
947+
This method accepts a string or an array of columns.
948+
949+
$builder->updateFields()
950+
------------------------
951+
Allows manually setting the fields to be updated when performing upserts.
952+
953+
.. literalinclude:: query_builder/110.php
954+
955+
This method accepts a string, an array of columns, or RawSql. You can also
956+
specify an extra column to be updated that isn't included in the dataset.
957+
This can be done by setting the second parameter to ``true``.
958+
959+
.. literalinclude:: query_builder/111.php
960+
961+
Notice that the ``updated_at`` field is not inserted but is used on update.
962+
879963
*************
880964
Updating Data
881965
*************
@@ -1667,6 +1751,31 @@ Class Reference
16671751

16681752
.. important:: This method is deprecated. It will be removed in future releases.
16691753

1754+
.. php:method:: upsert([$set = null[, $escape = null]])
1755+
:param array $set: An associative array of field/value pairs
1756+
:param bool $escape: Whether to escape values
1757+
:returns: ``true`` on success, ``false`` on failure
1758+
:rtype: bool
1759+
1760+
Compiles and executes an ``UPSERT`` statement.
1761+
1762+
.. php:method:: upsertBatch([$set = null[, $escape = null[, $batch_size = 100]]])
1763+
:param array $set: Data to upsert
1764+
:param bool $escape: Whether to escape values
1765+
:param int $batch_size: Count of rows to upsert at once
1766+
:returns: Number of rows upserted or ``false`` on failure
1767+
:rtype: int|false
1768+
1769+
Compiles and executes batch ``UPSERT`` statements.
1770+
1771+
.. note:: MySQL uses ``ON DUPLICATE KEY UPDATE``, the affected-rows value
1772+
per row is 1 if the row is inserted as a new row, 2 if an existing row
1773+
is updated, and 0 if an existing row is set to its current values.
1774+
1775+
.. note:: When more than ``$batch_size`` rows are provided, multiple
1776+
``UPSERT`` queries will be executed, each trying to upsert
1777+
up to ``$batch_size`` rows.
1778+
16701779
.. php:method:: update([$set = null[, $where = null[, $limit = null]]])
16711780
16721781
:param array $set: An associative array of field/value pairs
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->upsertBatch($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')->setAlias('_upsert')->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 ("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+
*/
Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
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+
$additionalUpdateField = ['updated_at' => new RawSql('CURRENT_TIMESTAMP')];
19+
20+
$sql = $builder->setData($data)->updateFields($additionalUpdateField, true)->upsertBatch();
21+
/* MySQLi produces:
22+
INSERT INTO `db_user` (`country`, `email`, `name`)
23+
VALUES ('Iran','[email protected]','Ahmadinejad'),('El Salvador','[email protected]','Pedro')
24+
ON DUPLICATE KEY UPDATE
25+
`country` = VALUES(`country`),
26+
`email` = VALUES(`email`),
27+
`name` = VALUES(`name`),
28+
`updated_at` = CURRENT_TIMESTAMP
29+
*/

0 commit comments

Comments
 (0)