Query Builder Class

CodeIgniter gives you access to a Query Builder class. This pattern allows information to be retrieved, inserted, and updated in your database with minimal scripting. In some cases, only one or two lines of code are necessary to perform a database action. CodeIgniter does not require that each database table be its own class file. It instead provides a more simplified interface.

Beyond simplicity, a major benefit to using the Query Builder features is that it allows you to create database independent applications, since the query syntax is generated by each database adapter. It also allows for safer queries, since the values are escaped automatically by the system.

Note

CodeIgniter doesn’t support dots (.) in the table and column names. Since v4.5.0, database names with dots are supported.

SQL Injection Protection

You can generate SQL statements quite safely with the Query Builder. However, it is not designed to prevent SQL injection no matter what data you pass.

Arguments passed to the Query Builder can be:
  1. identifiers such as field (or table) names

  2. their values

  3. a part of SQL strings

The Query Builder will escape all values by default.

It will also try to properly protect identifiers and identifiers in SQL strings by default. However, it is implemented to work well in many use cases and is not designed to prevent all attacks. Therefore, you should never feed in user input to them without proper validation.

Also, many methods have the $escape parameter that can be set to disable escaping. If $escape is set to false, no protection is provided by the Query Builder, so you must ensure by yourself that they are properly escaped or protected before passing it to the Query Builder. The same is true when using RawSql, which specifies a raw SQL statement.

Loading the Query Builder

The Query Builder is loaded through the table() method on the database connection. This sets the FROM portion of the query for you and returns a new instance of the Query Builder class:

<?php

$db      = \Config\Database::connect();
$builder = $db->table('users');

The Query Builder is only loaded into memory when you specifically request the class, so no resources are used by default.

Selecting Data

The following methods allow you to build SQL SELECT statements.

Get

$builder->get()

Runs the selection query and returns the result. Can be used by itself to retrieve all records from a table:

<?php

$builder = $db->table('mytable');
$query   = $builder->get();  // Produces: SELECT * FROM mytable

The first and second parameters enable you to set a limit and offset clause:

<?php

$query = $builder->get(10, 20);
/*
 * Executes: SELECT * FROM mytable LIMIT 20, 10
 * (in MySQL. Other databases have slightly different syntax)
 */

You’ll notice that the above method is assigned to a variable named $query, which can be used to show the results:

<?php

$query = $builder->get();

foreach ($query->getResult() as $row) {
    echo $row->title;
}

Please visit the getResult() method for a full discussion regarding result generation.

$builder->getCompiledSelect()

Compiles the selection query just like $builder->get() but does not run the query. This method simply returns the SQL query as a string.

Example:

<?php

$sql = $builder->getCompiledSelect();
echo $sql;
// Prints string: SELECT * FROM mytable

The parameter (false) in the first query below enables you to set whether or not the query builder will be reset (because the default value of the parameter is true, getCompiledSelect(bool $reset = true), by default it will be reset just like when using $builder->get()):

<?php

echo $builder->limit(10, 20)->getCompiledSelect(false);
/*
 * Prints string: SELECT * FROM mytable LIMIT 20, 10
 * (in MySQL. Other databases have slightly different syntax)
 */

echo $builder->select('title, content, date')->getCompiledSelect();
// Prints string: SELECT title, content, date FROM mytable LIMIT 20, 10

The key thing to notice in the above example is that the second query did not utilize limit(10, 20) but the generated SQL query has LIMIT 20, 10. The reason for this outcome is because the parameter in the first query is set to false, limit(10, 20) remained in the second query.

$builder->getWhere()

Identical to the get() method except that it permits you to add a “where” clause in the first parameter, instead of using the $builder->where() method:

<?php

$query = $builder->getWhere(['id' => $id], $limit, $offset);

Please read about the where() method below for more information.

Select

$builder->select()

Permits you to write the SELECT portion of your query:

<?php

$builder->select('title, content, date');
$query = $builder->get();
// Executes: SELECT title, content, date FROM mytable

Note

If you are selecting all (*) from a table you do not need to use this method. When omitted, CodeIgniter assumes that you wish to select all fields and automatically adds SELECT *.

$builder->select() accepts an optional second parameter. If you set it to false, CodeIgniter will not try to protect your field or table names. This is useful if you need a compound select statement where automatic escaping of fields may break them.

<?php

$builder->select('(SELECT SUM(payments.amount) FROM payments WHERE payments.invoice_id=4) AS amount_paid', false);
$query = $builder->get();
RawSql

Added in version 4.2.0.

Since v4.2.0, $builder->select() accepts a CodeIgniter\Database\RawSql instance, which expresses raw SQL strings.

<?php

use CodeIgniter\Database\RawSql;

$sql = 'REGEXP_SUBSTR(ral_anno,"[0-9]{1,2}([,.][0-9]{1,3})([,.][0-9]{1,3})") AS ral';
$builder->select(new RawSql($sql));
$query = $builder->get();

Warning

When you use RawSql, you MUST escape the values and protect the identifiers manually. Failure to do so could result in SQL injections.

$builder->selectMax()

Writes a SELECT MAX(field) portion for your query. You can optionally include a second parameter to rename the resulting field.

<?php

$builder->selectMax('age');
$query = $builder->get();
// Produces: SELECT MAX(age) as age FROM mytable

$builder->selectMax('age', 'member_age');
$query = $builder->get();
// Produces: SELECT MAX(age) as member_age FROM mytable

$builder->selectMin()

Writes a SELECT MIN(field) portion for your query. As with selectMax(), you can optionally include a second parameter to rename the resulting field.

<?php

$builder->selectMin('age');
$query = $builder->get();
// Produces: SELECT MIN(age) as age FROM mytable

$builder->selectAvg()

Writes a SELECT AVG(field) portion for your query. As with selectMax(), you can optionally include a second parameter to rename the resulting field.

<?php

$builder->selectAvg('age');
$query = $builder->get();
// Produces: SELECT AVG(age) as age FROM mytable

$builder->selectSum()

Writes a SELECT SUM(field) portion for your query. As with selectMax(), you can optionally include a second parameter to rename the resulting field.

<?php

$builder->selectSum('age');
$query = $builder->get();
// Produces: SELECT SUM(age) as age FROM mytable

$builder->selectCount()

Writes a SELECT COUNT(field) portion for your query. As with selectMax(), you can optionally include a second parameter to rename the resulting field.

Note

This method is particularly helpful when used with groupBy(). For counting results generally see countAll() or countAllResults().

<?php

$builder->selectCount('age');
$query = $builder->get();
// Produces: SELECT COUNT(age) as age FROM mytable

$builder->selectSubquery()

Adds a subquery to the SELECT section.

$subquery = $db->table('countries')->select('name')->where('id', 1);
$builder  = $db->table('users')->select('name')->selectSubquery($subquery, 'country');
$query    = $builder->get();
// Produces: SELECT `name`, (SELECT `name` FROM `countries` WHERE `id` = 1) `country` FROM `users`

From

$builder->from()

Permits you to write the FROM portion of your query:

<?php

$builder = $db->table('users');
$builder->select('title, content, date');
$builder->from('mytable');
$query = $builder->get();
// Produces: SELECT title, content, date FROM users, mytable

Note

As shown earlier, the FROM portion of your query can be specified in the $db->table() method. Additional calls to from() will add more tables to the FROM portion of your query.

Subqueries

$builder->fromSubquery()

Permits you to write part of a FROM query as a subquery.

This is where we add a subquery to an existing table:

<?php

$subquery = $db->table('users');
$builder  = $db->table('jobs')->fromSubquery($subquery, 'alias');
$query    = $builder->get();
// Produces: SELECT * FROM `jobs`, (SELECT * FROM `users`) `alias`

Use the $db->newQuery() method to make a subquery the main table:

<?php

$subquery = $db->table('users')->select('id, name');
$builder  = $db->newQuery()->fromSubquery($subquery, 't');
$query    = $builder->get();
// Produces: SELECT * FROM (SELECT `id`, `name` FROM users) `t`

Join

$builder->join()

Permits you to write the JOIN portion of your query:

<?php

$builder = $db->table('blogs');
$builder->select('*');
$builder->join('comments', 'comments.id = blogs.id');
$query = $builder->get();
/*
 * Produces:
 * SELECT * FROM blogs JOIN comments ON comments.id = blogs.id
 */

Multiple method calls can be made if you need several joins in one query.

If you need a specific type of JOIN you can specify it via the third parameter of the method. Options are: left, right, outer, inner, left outer, and right outer.

<?php

$builder->join('comments', 'comments.id = blogs.id', 'left');
// Produces: LEFT JOIN comments ON comments.id = blogs.id
RawSql

Added in version 4.2.0.

Since v4.2.0, $builder->join() accepts a CodeIgniter\Database\RawSql instance as the JOIN ON condition, which expresses raw SQL strings.

<?php

use CodeIgniter\Database\RawSql;

$sql = 'user.id = device.user_id AND ((1=1 OR 1=1) OR (1=1 OR 1=1))';
$builder->join('user', new RawSql($sql), 'LEFT');
// Produces: LEFT JOIN "user" ON user.id = device.user_id AND ((1=1 OR 1=1) OR (1=1 OR 1=1))

Warning

When you use RawSql, you MUST escape the values and protect the identifiers manually. Failure to do so could result in SQL injections.

Looking for Specific Data

Where

$builder->where()

This method enables you to set WHERE clauses using one of five methods:

Note

All values passed to this method are escaped automatically, producing safer queries, except when using a custom string.

Note

$builder->where() accepts an optional third parameter. If you set it to false, CodeIgniter will not try to protect your field or table names.

1. Simple key/value method
<?php

$builder->where('name', $name);
// Produces: WHERE name = 'Joe'

Notice that the equal sign is added for you.

If you use multiple method calls they will be chained together with AND between them:

<?php

$builder->where('name', $name);
$builder->where('title', $title);
$builder->where('status', $status);
// WHERE name = 'Joe' AND title = 'boss' AND status = 'active'
2. Custom key/value method

You can include an operator in the first parameter in order to control the comparison:

<?php

$builder->where('name !=', $name);
$builder->where('id <', $id);
// Produces: WHERE name != 'Joe' AND id < 45
3. Associative array method
<?php

$array = ['name' => $name, 'title' => $title, 'status' => $status];
$builder->where($array);
// Produces: WHERE name = 'Joe' AND title = 'boss' AND status = 'active'

You can include your own operators using this method as well:

<?php

$array = ['name !=' => $name, 'id <' => $id, 'date >' => $date];
$builder->where($array);
4. Custom string

You can write your own clauses manually:

<?php

$where = "name='Joe' AND status='boss' OR status='active'";
$builder->where($where);

Warning

If you are using user-supplied data within the string, you MUST escape the values and protect the identifiers manually. Failure to do so could result in SQL injections.

<?php

$name  = $builder->db->escape('Joe');
$where = "name={$name} AND status='boss' OR status='active'";
$builder->where($where);
5. RawSql

Added in version 4.2.0.

Since v4.2.0, $builder->where() accepts a CodeIgniter\Database\RawSql instance, which expresses raw SQL strings.

<?php

use CodeIgniter\Database\RawSql;

$sql = "id > 2 AND name != 'Accountant'";
$builder->where(new RawSql($sql));

Warning

When you use RawSql, you MUST escape the values and protect the identifiers manually. Failure to do so could result in SQL injections.

6. Subqueries
<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->where('advance_amount <', static function (BaseBuilder $builder) {
    $builder->select('MAX(advance_amount)', false)->from('orders')->where('id >', 2);
});
// Produces: WHERE "advance_amount" < (SELECT MAX(advance_amount) FROM "orders" WHERE "id" > 2)

// With builder directly
$subQuery = $db->table('orders')->select('MAX(advance_amount)', false)->where('id >', 2);
$builder->where('advance_amount <', $subQuery);

$builder->orWhere()

This method is identical to the one above, except that multiple instances are joined by OR:

<?php

$builder->where('name !=', $name);
$builder->orWhere('id >', $id);
// Produces: WHERE name != 'Joe' OR id > 50

$builder->whereIn()

Generates a WHERE field IN (‘item’, ‘item’) SQL query joined with AND if appropriate:

<?php

$names = ['Frank', 'Todd', 'James'];
$builder->whereIn('username', $names);
// Produces: WHERE username IN ('Frank', 'Todd', 'James')

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->whereIn('id', static function (BaseBuilder $builder) {
    $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});
// Produces: WHERE "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3);
$builder->whereIn('id', $subQuery);

$builder->orWhereIn()

Generates a WHERE field IN (‘item’, ‘item’) SQL query joined with OR if appropriate:

<?php

$names = ['Frank', 'Todd', 'James'];
$builder->orWhereIn('username', $names);
// Produces: OR username IN ('Frank', 'Todd', 'James')

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->orWhereIn('id', static function (BaseBuilder $builder) {
    $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});
// Produces: OR "id" IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3);
$builder->orWhereIn('id', $subQuery);

$builder->whereNotIn()

Generates a WHERE field NOT IN (‘item’, ‘item’) SQL query joined with AND if appropriate:

<?php

$names = ['Frank', 'Todd', 'James'];
$builder->whereNotIn('username', $names);
// Produces: WHERE username NOT IN ('Frank', 'Todd', 'James')

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->whereNotIn('id', static function (BaseBuilder $builder) {
    $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});
// Produces: WHERE "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3);
$builder->whereNotIn('id', $subQuery);

$builder->orWhereNotIn()

Generates a WHERE field NOT IN (‘item’, ‘item’) SQL query joined with OR if appropriate:

<?php

$names = ['Frank', 'Todd', 'James'];
$builder->orWhereNotIn('username', $names);
// Produces: OR username NOT IN ('Frank', 'Todd', 'James')

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->orWhereNotIn('id', static function (BaseBuilder $builder) {
    $builder->select('job_id')->from('users_jobs')->where('user_id', 3);
});
// Produces: OR "id" NOT IN (SELECT "job_id" FROM "users_jobs" WHERE "user_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('job_id')->where('user_id', 3);
$builder->orWhereNotIn('id', $subQuery);

Looking for Similar Data

Like

$builder->like()

This method enables you to generate LIKE clauses, useful for doing searches.

Note

All values passed to this method are escaped automatically.

Note

All like* method variations can be forced to perform case-insensitive searches by passing a fifth parameter of true to the method. This will use platform-specific features where available otherwise, will force the values to be lowercase, i.e., WHERE LOWER(column) LIKE '%search%'. This may require indexes to be made for LOWER(column) instead of column to be effective.

1. Simple key/value method
<?php

$builder->like('title', 'match');
// Produces: WHERE `title` LIKE '%match%' ESCAPE '!'

If you use multiple method calls they will be chained together with AND between them:

<?php

$builder->like('title', 'match');
$builder->like('body', 'match');
// WHERE `title` LIKE '%match%' ESCAPE '!' AND  `body` LIKE '%match%' ESCAPE '!'

If you want to control where the wildcard (%) is placed, you can use an optional third argument. Your options are before, after and both (which is the default).

<?php

$builder->like('title', 'match', 'before'); // Produces: WHERE `title` LIKE '%match' ESCAPE '!'
$builder->like('title', 'match', 'after');  // Produces: WHERE `title` LIKE 'match%' ESCAPE '!'
$builder->like('title', 'match', 'both');   // Produces: WHERE `title` LIKE '%match%' ESCAPE '!'
2. Associative array method
<?php

$array = ['title' => $match, 'page1' => $match, 'page2' => $match];
$builder->like($array);
/*
 * WHERE `title` LIKE '%match%' ESCAPE '!'
 *     AND  `page1` LIKE '%match%' ESCAPE '!'
 *     AND  `page2` LIKE '%match%' ESCAPE '!'
 */
3. RawSql

Added in version 4.2.0.

Since v4.2.0, $builder->like() accepts a CodeIgniter\Database\RawSql instance, which expresses raw SQL strings.

<?php

use CodeIgniter\Database\RawSql;

$sql    = "CONCAT(users.name, ' ', IF(users.surname IS NULL OR users.surname = '', '', users.surname))";
$rawSql = new RawSql($sql);
$builder->like($rawSql, 'value', 'both');

Warning

When you use RawSql, you MUST escape the values and protect the identifiers manually. Failure to do so could result in SQL injections.

$builder->orLike()

This method is identical to the one above, except that multiple instances are joined by OR:

<?php

$builder->like('title', 'match');
$builder->orLike('body', $match);
// WHERE `title` LIKE '%match%' ESCAPE '!' OR  `body` LIKE '%match%' ESCAPE '!'

$builder->notLike()

This method is identical to like(), except that it generates NOT LIKE statements:

<?php

$builder->notLike('title', 'match'); // WHERE `title` NOT LIKE '%match% ESCAPE '!'

$builder->orNotLike()

This method is identical to notLike(), except that multiple instances are joined by OR:

<?php

$builder->like('title', 'match');
$builder->orNotLike('body', 'match');
// WHERE `title` LIKE '%match% OR  `body` NOT LIKE '%match%' ESCAPE '!'

$builder->groupBy()

Permits you to write the GROUP BY portion of your query:

<?php

$builder->groupBy('title');
// Produces: GROUP BY title

You can also pass an array of multiple values as well:

<?php

$builder->groupBy(['title', 'date']);
// Produces: GROUP BY title, date

$builder->distinct()

Adds the DISTINCT keyword to a query

<?php

$builder->distinct();
$builder->get();
// Produces: SELECT DISTINCT * FROM mytable

$builder->having()

Permits you to write the HAVING portion of your query. There are 2 possible syntaxes, 1 argument or 2:

<?php

$builder->having('user_id = 45'); // Produces: HAVING user_id = 45
$builder->having('user_id', 45); // Produces: HAVING user_id = 45

You can also pass an array of multiple values as well:

<?php

$builder->having(['title =' => 'My Title', 'id <' => $id]);
// Produces: HAVING title = 'My Title', id < 45

If you are using a database that CodeIgniter escapes values for, you can prevent escaping content by passing an optional third argument, and setting it to false.

<?php

$builder->having('user_id', 45); // Produces: HAVING `user_id` = 45 in some databases such as MySQL
$builder->having('user_id', 45, false); // Produces: HAVING user_id = 45

$builder->orHaving()

Identical to having(), only separates multiple clauses with OR.

$builder->havingIn()

Generates a HAVING field IN (‘item’, ‘item’) SQL query joined with AND if appropriate:

<?php

$groups = [1, 2, 3];
$builder->havingIn('group_id', $groups);
// Produces: HAVING group_id IN (1, 2, 3)

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->havingIn('id', static function (BaseBuilder $builder) {
    $builder->select('user_id')->from('users_jobs')->where('group_id', 3);
});
// Produces: HAVING "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3);
$builder->havingIn('id', $subQuery);

$builder->orHavingIn()

Generates a HAVING field IN (‘item’, ‘item’) SQL query joined with OR if appropriate

<?php

$groups = [1, 2, 3];
$builder->orHavingIn('group_id', $groups);
// Produces: OR group_id IN (1, 2, 3)

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->orHavingIn('id', static function (BaseBuilder $builder) {
    $builder->select('user_id')->from('users_jobs')->where('group_id', 3);
});
// Produces: OR "id" IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3);
$builder->orHavingIn('id', $subQuery);

$builder->havingNotIn()

Generates a HAVING field NOT IN (‘item’, ‘item’) SQL query joined with AND if appropriate

<?php

$groups = [1, 2, 3];
$builder->havingNotIn('group_id', $groups);
// Produces: HAVING group_id NOT IN (1, 2, 3)

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->havingNotIn('id', static function (BaseBuilder $builder) {
    $builder->select('user_id')->from('users_jobs')->where('group_id', 3);
});
// Produces: HAVING "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3);
$builder->havingNotIn('id', $subQuery);

$builder->orHavingNotIn()

Generates a HAVING field NOT IN (‘item’, ‘item’) SQL query joined with OR if appropriate

<?php

$groups = [1, 2, 3];
$builder->havingNotIn('group_id', $groups);
// Produces: OR group_id NOT IN (1, 2, 3)

You can use subqueries instead of an array of values:

<?php

// With closure
use CodeIgniter\Database\BaseBuilder;

$builder->orHavingNotIn('id', static function (BaseBuilder $builder) {
    $builder->select('user_id')->from('users_jobs')->where('group_id', 3);
});
// Produces: OR "id" NOT IN (SELECT "user_id" FROM "users_jobs" WHERE "group_id" = 3)

// With builder directly
$subQuery = $db->table('users_jobs')->select('user_id')->where('group_id', 3);
$builder->orHavingNotIn('id', $subQuery);

$builder->havingLike()

This method enables you to generate LIKE clauses for HAVING part or the query, useful for doing searches.

Note

All values passed to this method are escaped automatically.

Note

All havingLike*() method variations can be forced to perform case-insensitive searches by passing a fifth parameter of true to the method. This will use platform-specific features where available otherwise, will force the values to be lowercase, i.e., HAVING LOWER(column) LIKE '%search%'. This may require indexes to be made for LOWER(column) instead of column to be effective.

1. Simple key/value method
<?php

$builder->havingLike('title', 'match');
// Produces: HAVING `title` LIKE '%match%' ESCAPE '!'

If you use multiple method calls they will be chained together with AND between them:

<?php

$builder->havingLike('title', 'match');
$builder->havingLike('body', 'match');
// HAVING `title` LIKE '%match%' ESCAPE '!' AND  `body` LIKE '%match% ESCAPE '!'

If you want to control where the wildcard (%) is placed, you can use an optional third argument. Your options are before, after and both (which is the default).

<?php

$builder->havingLike('title', 'match', 'before'); // Produces: HAVING `title` LIKE '%match' ESCAPE '!'
$builder->havingLike('title', 'match', 'after');  // Produces: HAVING `title` LIKE 'match%' ESCAPE '!'
$builder->havingLike('title', 'match', 'both');   // Produces: HAVING `title` LIKE '%match%' ESCAPE '!'
2. Associative array method
<?php

$array = ['title' => $match, 'page1' => $match, 'page2' => $match];
$builder->havingLike($array);
/*
 *  HAVING `title` LIKE '%match%' ESCAPE '!'
 *      AND  `page1` LIKE '%match%' ESCAPE '!'
 *      AND  `page2` LIKE '%match%' ESCAPE '!'
 */

$builder->orHavingLike()

This method is identical to the one above, except that multiple instances are joined by OR:

<?php

$builder->havingLike('title', 'match');
$builder->orHavingLike('body', $match);
// HAVING `title` LIKE '%match%' ESCAPE '!' OR  `body` LIKE '%match%' ESCAPE '!'

$builder->notHavingLike()

This method is identical to havingLike(), except that it generates NOT LIKE statements:

<?php

$builder->notHavingLike('title', 'match');
// HAVING `title` NOT LIKE '%match% ESCAPE '!'

$builder->orNotHavingLike()

This method is identical to notHavingLike(), except that multiple instances are joined by OR:

<?php

$builder->havingLike('title', 'match');
$builder->orNotHavingLike('body', 'match');
// HAVING `title` LIKE '%match% OR  `body` NOT LIKE '%match%' ESCAPE '!'

Ordering Results

OrderBy

$builder->orderBy()

Lets you set an ORDER BY clause.

The first parameter contains the name of the column you would like to order by.

The second parameter lets you set the direction of the result. Options are ASC, DESC AND RANDOM.

<?php

$builder->orderBy('title', 'DESC');
// Produces: ORDER BY `title` DESC

You can also pass your own string in the first parameter:

<?php

$builder->orderBy('title DESC, name ASC');
// Produces: ORDER BY `title` DESC, `name` ASC

Or multiple method calls can be made if you need multiple fields.

<?php

$builder->orderBy('title', 'DESC');
$builder->orderBy('name', 'ASC');
// Produces: ORDER BY `title` DESC, `name` ASC

If you choose the RANDOM direction option, then the first parameters will be ignored, unless you specify a numeric seed value.

<?php

$builder->orderBy('title', 'RANDOM');
// Produces: ORDER BY RAND()

$builder->orderBy(42, 'RANDOM');
// Produces: ORDER BY RAND(42)

Limiting or Counting Results

Limit

$builder->limit()

Lets you limit the number of rows you would like returned by the query:

<?php

$builder->limit(10);
// Produces: LIMIT 10

Note

If LIMIT 0 is specified in a SQL statement, 0 records are returned. However, there is a bug in the Query Builder, and if limit(0) is specified, the generated SQL statement will have no LIMIT clause and all records will be returned. To fix the incorrect behavior, a setting was added in v4.5.0. See limit(0) Behavior for details. The incorrect behavior will be fixed in a future version, so it is recommended that you change the default setting.

The second parameter lets you set a result offset.

<?php

$builder->limit(10, 20);
// Produces: LIMIT 20, 10 (in MySQL. Other databases have slightly different syntax)

$builder->countAllResults()

Permits you to determine the number of rows in a particular Query Builder query. Queries will accept Query Builder restrictors such as where(), orWhere(), like(), orLike(), etc. Example:

<?php

echo $builder->countAllResults(); // Produces an integer, like 25
$builder->like('title', 'match');
$builder->from('my_table');
echo $builder->countAllResults(); // Produces an integer, like 17

However, this method also resets any field values that you may have passed to select(). If you need to keep them, you can pass false as the first parameter.

<?php

echo $builder->countAllResults(false); // Produces an integer, like 17

$builder->countAll()

Permits you to determine the number of rows in a particular table. Example:

<?php

echo $builder->countAll(); // Produces an integer, like 25

As is in countAllResult() method, this method resets any field values that you may have passed to select() as well. If you need to keep them, you can pass false as the first parameter.

Union queries

Union

$builder->union()

Is used to combine the result-set of two or more SELECT statements. It will return only the unique results.

<?php

$builder = $db->table('users')->select('id, name')->limit(10);
$union   = $db->table('groups')->select('id, name');
$builder->union($union)->get();
/*
 * Produces:
 * SELECT * FROM (SELECT `id`, `name` FROM `users` LIMIT 10) uwrp0
 * UNION SELECT * FROM (SELECT `id`, `name` FROM `groups`) uwrp1
 */

Note

For correct work with DBMS (such as MSSQL and Oracle) queries are wrapped in SELECT * FROM ( ... ) alias The main query will always have an alias of uwrp0. Each subsequent query added via union() will have an alias uwrpN+1.

All union queries will be added after the main query, regardless of the order in which the union() method was called. That is, the limit() or orderBy() methods will be relative to the main query, even if called after union().

In some cases, it may be necessary, for example, to sort or limit the number of records of the query result. The solution is to use the wrapper created via $db->newQuery(). In the example below, we get the first 5 users + the last 5 users and sort the result by id:

<?php

$union   = $db->table('users')->select('id, name')->orderBy('id', 'DESC')->limit(5);
$builder = $db->table('users')->select('id, name')->orderBy('id', 'ASC')->limit(5)->union($union);

$db->newQuery()->fromSubquery($builder, 'q')->orderBy('id', 'DESC')->get();
/*
 * Produces:
 * SELECT * FROM (
 *      SELECT * FROM (SELECT `id`, `name` FROM `users` ORDER BY `id` ASC LIMIT 5) uwrp0
 *      UNION
 *      SELECT * FROM (SELECT `id`, `name` FROM `users` ORDER BY `id` DESC LIMIT 5) uwrp1
 * ) q ORDER BY `id` DESC
 */

$builder->unionAll()

The behavior is the same as the union() method. However, all results will be returned, not just the unique ones.

Query grouping

Group

Query grouping allows you to create groups of WHERE clauses by enclosing them in parentheses. This will allow you to create queries with complex WHERE clauses. Nested groups are supported. Example:

<?php

$builder->select('*')->from('my_table')
    ->groupStart()
        ->where('a', 'a')
        ->orGroupStart()
            ->where('b', 'b')
            ->where('c', 'c')
        ->groupEnd()
    ->groupEnd()
    ->where('d', 'd')
    ->get();
/*
 * Generates:
 * SELECT * FROM (`my_table`) WHERE ( `a` = 'a' OR ( `b` = 'b' AND `c` = 'c' ) ) AND `d` = 'd'
 */

Note

Groups need to be balanced, make sure every groupStart() is matched by a groupEnd().

$builder->groupStart()

Starts a new group by adding an opening parenthesis to the WHERE clause of the query.

$builder->orGroupStart()

Starts a new group by adding an opening parenthesis to the WHERE clause of the query, prefixing it with OR.

$builder->notGroupStart()

Starts a new group by adding an opening parenthesis to the WHERE clause of the query, prefixing it with NOT.

$builder->orNotGroupStart()

Starts a new group by adding an opening parenthesis to the WHERE clause of the query, prefixing it with OR NOT.

$builder->groupEnd()

Ends the current group by adding a closing parenthesis to the WHERE clause of the query.

$builder->havingGroupStart()

Starts a new group by adding an opening parenthesis to the HAVING clause of the query.

$builder->orHavingGroupStart()

Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with OR.

$builder->notHavingGroupStart()

Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with NOT.

$builder->orNotHavingGroupStart()

Starts a new group by adding an opening parenthesis to the HAVING clause of the query, prefixing it with OR NOT.

$builder->havingGroupEnd()

Ends the current group by adding a closing parenthesis to the HAVING clause of the query.

Inserting Data

Insert

$builder->insert()

Generates an insert string based on the data you supply, and runs the query. You can either pass an array or an object to the method. Here is an example using an array:

<?php

use CodeIgniter\Database\RawSql;

$data = [
    'id'          => new RawSql('DEFAULT'),
    'title'       => 'My title',
    'name'        => 'My Name',
    'date'        => '2022-01-01',
    'last_update' => new RawSql('CURRENT_TIMESTAMP()'),
];

$builder->insert($data);
/* Produces:
    INSERT INTO mytable (id, title, name, date, last_update)
    VALUES (DEFAULT, 'My title', 'My name', '2022-01-01', CURRENT_TIMESTAMP())
*/

The first parameter is an associative array of values.

Note

All values except RawSql are escaped automatically producing safer queries.

Warning

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

Here is an example using an object:

<?php

namespace App\Libraries;

class MyClass
{
    public $title   = 'My Title';
    public $content = 'My Content';
    public $date    = 'My Date';
}
<?php

use App\Libraries\MyClass;

$object = new MyClass();
$builder->insert($object);
// Produces: INSERT INTO mytable (title, content, date) VALUES ('My Title', 'My Content', 'My Date')

The first parameter is an object.

$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 method. Can also be used on insertBatch, update and delete (when supported). Here is an example using the array of the above example:

<?php

$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 run the query. This method simply returns the SQL query as a string.

Example:

<?php

$data = [
    'title' => 'My title',
    'name'  => 'My Name',
    'date'  => 'My date',
];

$sql = $builder->set($data)->getCompiledInsert();
echo $sql;
// Produces string: INSERT INTO mytable (`title`, `name`, `date`) VALUES ('My title', 'My name', 'My date')

The first parameter enables you to set whether or not the query builder query will be reset (by default it will be–just like $builder->insert()):

<?php

echo $builder->set('title', 'My Title')->getCompiledInsert(false);
// Produces string: INSERT INTO mytable (`title`) VALUES ('My Title')

echo $builder->set('content', 'My Content')->getCompiledInsert();
// Produces string: INSERT INTO mytable (`title`, `content`) VALUES ('My Title', 'My Content')

The reason the second query worked is that the first parameter is set to false.

Note

This method doesn’t work for batch inserts.

insertBatch

$builder->insertBatch()

Insert from Data

Generates an insert string based on the data you supply, and runs the query. You can either pass an array or an object to the method. Here is an example using an array:

<?php

$data = [
    [
        'title' => 'My title',
        'name'  => 'My Name',
        'date'  => 'My date',
    ],
    [
        'title' => 'Another title',
        'name'  => 'Another Name',
        'date'  => 'Another date',
    ],
];

$builder->insertBatch($data);
/*
 * Produces:
 * INSERT INTO mytable (title, name, date)
 *      VALUES ('My title', 'My name', 'My date'),
 *      ('Another title', 'Another name', 'Another date')
 */

The first parameter is an associative array of values.

Note

All values except RawSql are escaped automatically producing safer queries.

Warning

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

Insert from a Query

You can also insert from a query:

<?php

use CodeIgniter\Database\RawSql;

$query = 'SELECT user2.name, user2.email, user2.country
          FROM user2
          LEFT JOIN user ON user.email = user2.email
          WHERE user.email IS NULL';

$sql = $builder
    ->ignore(true)
    ->setQueryAsData(new RawSql($query), null, 'name, country, email')
    ->insertBatch();
/* MySQLi produces:
    INSERT IGNORE INTO `db_user` (`name`, `country`, `email`)
    SELECT user2.name, user2.email, user2.country
    FROM user2
    LEFT JOIN user ON user.email = user2.email
    WHERE user.email IS NULL
*/

Note

setQueryAsData() can be used since v4.3.0.

Note

It is required to alias the columns of the select query to match those of the target table.

Upserting Data

Upsert

$builder->upsert()

Added in version 4.3.0.

Generates an upsert string based on the data you supply, and runs the query. You can either pass an array or an object to the method. By default a constraint will be defined in order. A primary key will be selected first and then unique keys. MySQL will use any constraint by default. Here is an example using an array:

<?php

$data = [
    'email'   => 'ahmadinejad@example.com',
    'name'    => 'Ahmadinejad',
    'country' => 'Iran',
];

$builder->upsert($data);
// MySQLi  produces: INSERT INTO.. ON DUPLICATE KEY UPDATE..
// Postgre produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
// SQLite3 produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
// SQLSRV  produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
// OCI8    produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..

The first parameter is an associative array of values.

Here is an example using an object:

<?php

namespace App\Libraries;

class MyClass
{
    public $email   = 'ahmadinejad@example.com';
    public $name    = 'Ahmadinejad';
    public $country = 'Iran';
}
<?php

use App\Libraries\MyClass;

$object = new MyClass();
$builder->upsert($object);

The first parameter is an object.

Note

All values are escaped automatically producing safer queries.

$builder->getCompiledUpsert()

Added in version 4.3.0.

Compiles the upsert query just like $builder->upsert() but does not run the query. This method simply returns the SQL query as a string.

Example:

<?php

$data = [
    'email'   => 'ahmadinejad@example.com',
    'name'    => 'Ahmadinejad',
    'country' => 'Iran',
];

$sql = $builder->setData($data)->getCompiledUpsert();
echo $sql;
/* MySQLi produces:
    INSERT INTO `db_user` (`country`, `email`, `name`)
    VALUES ('Iran','ahmadinejad@example.com','Ahmadinejad')
    ON DUPLICATE KEY UPDATE
    `country` = VALUES(`country`),
    `email` = VALUES(`email`),
    `name` = VALUES(`name`)
*/

Note

This method doesn’t work for batch upserts.

upsertBatch

$builder->upsertBatch()

Added in version 4.3.0.

Upsert from Data

Generates an upsert string based on the data you supply, and runs the query. You can either pass an array or an object to the method. By default a constraint will be defined in order. A primary key will be selected first and then unique keys. MySQL will use any constraint by default.

Here is an example using an array:

<?php

$data = [
    [
        'id'      => 2,
        'email'   => 'ahmadinejad@example.com',
        'name'    => 'Ahmadinejad',
        'country' => 'Iran',
    ],
    [
        'id'      => null,
        'email'   => 'pedro@example.com',
        'name'    => 'Pedro',
        'country' => 'El Salvador',
    ],
];

$builder->upsertBatch($data);
// MySQLi  produces: INSERT INTO.. ON DUPLICATE KEY UPDATE..
// Postgre produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
// SQLite3 produces: INSERT INTO.. ON CONFLICT.. DO UPDATE..
// SQLSRV  produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..
// OCI8    produces: MERGE INTO.. WHEN MATCHED THEN UPDATE.. WHEN NOT MATCHED THEN INSERT..

The first parameter is an associative array of values.

Note

All values are escaped automatically producing safer queries.

Upsert from a Query

You can also upsert from a query:

<?php

use CodeIgniter\Database\RawSql;

$query = $this->db->table('user2')
    ->select('user2.name, user2.email, user2.country')
    ->join('user', 'user.email = user2.email', 'left')
    ->where('user.email IS NULL');

$additionalUpdateField = ['updated_at' => new RawSql('CURRENT_TIMESTAMP')];

$sql = $builder->setQueryAsData($query)
    ->onConstraint('email')
    ->updateFields($additionalUpdateField, true)
    ->upsertBatch();
/* MySQLi produces:
    INSERT INTO `db_user` (`country`, `email`, `name`)
    SELECT user2.name, user2.email, user2.country
    FROM user2
    LEFT JOIN user ON user.email = user2.email
    WHERE user.email IS NULL
    ON DUPLICATE KEY UPDATE
    `country` = VALUES(`country`),
    `email` = VALUES(`email`),
    `name` = VALUES(`name`),
    `updated_at` = CURRENT_TIMESTAMP
*/

Note

The setQueryAsData(), onConstraint(), and updateFields() methods can be used since v4.3.0.

Note

It is required to alias the columns of the select query to match those of the target table.

$builder->onConstraint()

Added in version 4.3.0.

Allows manually setting constraint to be used for upsert. This does not work with MySQL because MySQL checks all constraints by default.

<?php

$data = [
    'id'      => 2,
    'email'   => 'ahmadinejad@example.com',
    'name'    => 'Ahmadinejad',
    'country' => 'Iran',
];

$builder->onConstraint('email')->upsert($data);
/* Postgre produces:
    INSERT INTO "db_user"("country", "email", "id", "name")
    VALUES ('Iran','ahmadinejad@example.com',2,'Ahmadinejad')
    ON CONFLICT("email")
    DO UPDATE SET
    "country" = "excluded"."country",
    "id" = "excluded"."id",
    "name" = "excluded"."name"
*/

This method accepts a string or an array of columns.

$builder->updateFields()

Added in version 4.3.0.

Allows manually setting the fields to be updated when performing upserts.

<?php

$data = [
    'id'      => 2,
    'email'   => 'ahmadinejad@example.com',
    'name'    => 'Ahmadinejad Zaghari',
    'country' => 'Afghanistan',
];

$builder->updateFields('name, country')->setData($data, null, '_upsert')->upsert();
/* SQLSRV produces:
    MERGE INTO "test"."dbo"."db_user"
    USING (
     VALUES ('Iran','ahmadinejad@example.com',2,'Ahmadinejad')
    ) "_upsert" ("country", "email", "id", "name")
    ON ("test"."dbo"."db_user"."id" = "_upsert"."id")
    WHEN MATCHED THEN UPDATE SET
    "country" = "_upsert"."country",
    "name" = "_upsert"."name"
    WHEN NOT MATCHED THEN INSERT ("country", "email", "id", "name")
    VALUES ("_upsert"."country", "_upsert"."email", "_upsert"."id", "_upsert"."name");
*/

This method accepts a string, an array of columns, or RawSql. You can also specify an extra column to be updated that isn’t included in the dataset. This can be done by setting the second parameter to true.

<?php

use CodeIgniter\Database\RawSql;

$data = [
    [
        'id'      => 2,
        'email'   => 'ahmadinejad@example.com',
        'name'    => 'Ahmadinejad',
        'country' => 'Iran',
    ],
    [
        'id'      => null,
        'email'   => 'pedro@example.com',
        'name'    => 'Pedro',
        'country' => 'El Salvador',
    ],
];

$additionalUpdateField = ['updated_at' => new RawSql('CURRENT_TIMESTAMP')];

$sql = $builder->setData($data)->updateFields($additionalUpdateField, true)->upsertBatch();
/* MySQLi produces:
    INSERT INTO `db_user` (`country`, `email`, `name`)
    VALUES ('Iran','ahmadinejad@example.com','Ahmadinejad'),('El Salvador','pedro@example.com','Pedro')
    ON DUPLICATE KEY UPDATE
    `country` = VALUES(`country`),
    `email` = VALUES(`email`),
    `name` = VALUES(`name`),
    `updated_at` = CURRENT_TIMESTAMP
*/

Notice that the updated_at field is not inserted but is used on update.

Updating Data

Update

$builder->replace()

This method executes a REPLACE statement, which is basically the SQL standard for (optional) DELETE + INSERT, using PRIMARY and UNIQUE keys as the determining factor. In our case, it will save you from the need to implement complex logics with different combinations of select(), update(), delete() and insert() calls.

Example:

<?php

$data = [
    'title' => 'My title',
    'name'  => 'My Name',
    'date'  => 'My date',
];

$builder->replace($data);
// Executes: REPLACE INTO mytable (title, name, date) VALUES ('My title', 'My name', 'My date')

In the above example, if we assume that the title field is our primary key, then if a row containing My title as the title value, that row will be deleted with our new row data replacing it.

Usage of the set() method is also allowed and all values are automatically escaped, just like with insert().

$builder->set()

This method enables you to set values for inserts or updates.

It can be used instead of passing a data array directly to the insert() or update() methods:

<?php

$builder->set('name', $name);
$builder->insert();
// Produces: INSERT INTO mytable (`name`) VALUES ('{$name}')

If you use multiple method called they will be assembled properly based on whether you are doing an insert or an update:

<?php

$builder->set('name', $name);
$builder->set('title', $title);
$builder->set('status', $status);
$builder->insert();

set() will also accept an optional third parameter ($escape), that will prevent the values from being escaped if set to false. To illustrate the difference, here is set() used both with and without the escape parameter.

<?php

$builder->set('field', 'field+1', false);
$builder->where('id', 2);
$builder->update();
// gives UPDATE mytable SET field = field+1 WHERE `id` = 2

$builder->set('field', 'field+1');
$builder->where('id', 2);
$builder->update();
// gives UPDATE `mytable` SET `field` = 'field+1' WHERE `id` = 2

You can also pass an associative array to this method:

<?php

$array = [
    'name'   => $name,
    'title'  => $title,
    'status' => $status,
];

$builder->set($array);
$builder->insert();

Or an object:

<?php

namespace App\Libraries;

class MyClass
{
    public $title   = 'My Title';
    public $content = 'My Content';
    public $date    = 'My Date';
}
<?php

use App\Libraries\MyClass;

$object = new MyClass();
$builder->set($object);
$builder->insert();

$builder->update()

Generates an update string and runs the query based on the data you supply. You can pass an array or an object to the method. Here is an example using an array:

<?php

$data = [
    'title' => $title,
    'name'  => $name,
    'date'  => $date,
];

$builder->where('id', $id);
$builder->update($data);
/*
 * Produces:
 * UPDATE mytable
 * SET title = '{$title}', name = '{$name}', date = '{$date}'
 * WHERE id = $id
 */

Or you can supply an object:

<?php

namespace App\Libraries;

class MyClass
{
    public $title   = 'My Title';
    public $content = 'My Content';
    public $date    = 'My Date';
}
<?php

use App\Libraries\MyClass;

$object = new MyClass();
$builder->where('id', $id);
$builder->update($object);
/*
 * Produces:
 * UPDATE `mytable`
 * SET `title` = '{$title}', `content` = '{$content}', `date` = '{$date}'
 * WHERE id = `$id`
 */

Note

All values except RawSql are escaped automatically producing safer queries.

Warning

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

You’ll notice the use of the $builder->where() method, enabling you to set the WHERE clause. You can optionally pass this information directly into the update() method as a string:

<?php

$builder->update($data, 'id = 4');

Or as an array:

<?php

$builder->update($data, ['id' => $id]);

You may also use the $builder->set() method described above when performing updates.

$builder->getCompiledUpdate()

This works exactly the same way as $builder->getCompiledInsert() except that it produces an UPDATE SQL string instead of an INSERT SQL string.

For more information view documentation for $builder->getCompiledInsert().

Note

This method doesn’t work for batched updates.

UpdateBatch

$builder->updateBatch()

Note

Since v4.3.0, the second parameter $index of updateBatch() has changed to $constraints. It now accepts types array, string, or RawSql.

Update from Data

Generates an update string based on the data you supply, and runs the query. You can either pass an array or an object to the method. Here is an example using an array:

<?php

$data = [
    [
        'title'  => 'Title 1',
        'author' => 'Author 1',
        'name'   => 'Name 1',
        'date'   => 'Date 1',
    ],
    [
        'title'  => 'Title 2',
        'author' => 'Author 2',
        'name'   => 'Name 2',
        'date'   => 'Date 2',
    ],
];
$builder->updateBatch($data, ['title', 'author']);
/*
 * Produces:
 * UPDATE `mytable`
 * INNER JOIN (
 * SELECT 'Title 1' `title`, 'Author 1' `author`, 'Name 1' `name`, 'Date 1' `date` UNION ALL
 * SELECT 'Title 2' `title`, 'Author 2' `author`, 'Name 2' `name`, 'Date 2' `date`
 * ) `u`
 * ON `mytable`.`title` = `u`.`title` AND `mytable`.`author` = `u`.`author`
 * SET
 * `mytable`.`title` = `u`.`title`,
 * `mytable`.`name` = `u`.`name`,
 * `mytable`.`date` = `u`.`date`
 */

The first parameter is an associative array of values, the second parameter is the where keys.

Note

Since v4.3.0, the generated SQL structure has been Improved.

Since v4.3.0, you can also use the onConstraint() and updateFields() methods:

<?php

use CodeIgniter\Database\RawSql;

$builder->setData($data)->onConstraint('title, author')->updateBatch();

// OR
$builder->setData($data, null, 'u')
    ->onConstraint(['`mytable`.`title`' => '`u`.`title`', 'author' => new RawSql('`u`.`author`')])
    ->updateBatch();

// OR
foreach ($data as $row) {
    $builder->setData($row);
}
$builder->onConstraint('title, author')->updateBatch();

// OR
$builder->setData($data, true, 'u')
    ->onConstraint(new RawSql('`mytable`.`title` = `u`.`title` AND `mytable`.`author` = `u`.`author`'))
    ->updateFields(['last_update' => new RawSql('CURRENT_TIMESTAMP()')], true)
    ->updateBatch();
/*
 * Produces:
 * UPDATE `mytable`
 * INNER JOIN (
 * SELECT 'Title 1' `title`, 'Author 1' `author`, 'Name 1' `name`, 'Date 1' `date` UNION ALL
 * SELECT 'Title 2' `title`, 'Author 2' `author`, 'Name 2' `name`, 'Date 2' `date`
 * ) `u`
 * ON `mytable`.`title` = `u`.`title` AND `mytable`.`author` = `u`.`author`
 * SET
 * `mytable`.`title` = `u`.`title`,
 * `mytable`.`name` = `u`.`name`,
 * `mytable`.`date` = `u`.`date`,
 * `mytable`.`last_update` = CURRENT_TIMESTAMP() // this only applies to the last scenario
 */

Note

All values except RawSql are escaped automatically producing safer queries.

Warning

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

Note

affectedRows() won’t give you proper results with this method, due to the very nature of how it works. Instead, updateBatch() returns the number of rows affected.

Update from a Query

Since v4.3.0, you can also update from a query with the setQueryAsData() method:

<?php

use CodeIgniter\Database\RawSql;

$query = $this->db->table('user2')
    ->select('user2.name, user2.email, user2.country')
    ->join('user', 'user.email = user2.email', 'inner')
    ->where('user2.country', 'US');

$additionalUpdateField = ['updated_at' => new RawSql('CURRENT_TIMESTAMP')];

$sql = $builder->table('user')
    ->setQueryAsData($query, null, 'u')
    ->onConstraint('email')
    ->updateFields($additionalUpdateField, true)
    ->updateBatch();
/*
 * Produces:
 * UPDATE `user`
 * INNER JOIN (
 * SELECT user2.name, user2.email, user2.country
 * FROM user2
 * INNER JOIN user ON user.email = user2.email
 * WHERE user2.country = 'US'
 * ) `u`
 * ON `user`.`email` = `u`.`email`
 * SET
 * `mytable`.`name` = `u`.`name`,
 * `mytable`.`email` = `u`.`email`,
 * `mytable`.`country` = `u`.`country`,
 * `mytable`.`updated_at` = CURRENT_TIMESTAMP()
 */

Note

It is required to alias the columns of the select query to match those of the target table.

Deleting Data

Delete

$builder->delete()

Generates a DELETE SQL string and runs the query.

<?php

$builder->delete(['id' => $id]);
// Produces: DELETE FROM mytable WHERE id = $id

The first parameter is the where clause. You can also use the where() or orWhere() methods instead of passing the data to the first parameter of the method:

<?php

$builder->where('id', $id);
$builder->delete();
/*
 * Produces:
 * DELETE FROM mytable
 * WHERE id = $id
 */

If you want to delete all data from a table, you can use the truncate() method, or emptyTable().

$builder->getCompiledDelete()

This works exactly the same way as $builder->getCompiledInsert() except that it produces a DELETE SQL string instead of an INSERT SQL string.

For more information view documentation for $builder->getCompiledInsert().

DeleteBatch

$builder->deleteBatch()

Added in version 4.3.0.

Delete from Data

Generates a batch DELETE statement based on a set of data.

<?php

$data = [
    [
        'order'   => 48372,
        'line'    => 3,
        'product' => 'Keyboard',
        'qty'     => 1,
    ],
    [
        'order'   => 48372,
        'line'    => 4,
        'product' => 'Mouse',
        'qty'     => 1,
    ],
    [
        'order'   => 48372,
        'line'    => 5,
        'product' => 'Monitor',
        'qty'     => 2,
    ],
];

$builder->setData($data, true, 'del')
    ->onConstraint('order, line')
    ->where('del.qty >', 1)
    ->deleteBatch();

/*
 * MySQL Produces:
 * DELETE `order_line` FROM `order_line`
 * INNER JOIN (
 * SELECT 3 `line`, 48372 `order`, 'Keyboard' `product`, 1 `qty` UNION ALL
 * SELECT 4 `line`, 48372 `order`, 'Mouse'    `product`, 1 `qty` UNION ALL
 * SELECT 5 `line`, 48372 `order`, 'Monitor'  `product`, 2 `qty`
 * ) `del`
 * ON `order_line`.`order` = `del`.`order` AND `order_line`.`line` = `del`.`line`
 * WHERE `del`.`qty` > 1
 */

This method may be especially useful when deleting data in a table with a composite primary key.

Note

SQLite3 does not support the use of where().

Delete from a Query

You can also delete from a query:

<?php

use CodeIgniter\Database\RawSql;

$query = $this->db->table('user2')->select('email, name, country')->where('country', 'Greece');

$this->db->table('user')
    ->setQueryAsData($query, 'alias')
    ->onConstraint('email')
    ->where('alias.name = user.name')
    ->deleteBatch();

/* MySQLi produces:
    DELETE `user` FROM `user`
    INNER JOIN (
    SELECT `email`, `name`, `country`
    FROM `user2`
    WHERE `country` = 'Greece') `alias`
    ON `user`.`email` = `alias`.`email`
    WHERE `alias`.`name` = `user`.`name`
*/

$builder->emptyTable()

Generates a DELETE SQL string and runs the query:

<?php

$builder->emptyTable('mytable');
// Produces: DELETE FROM mytable

$builder->truncate()

Generates a TRUNCATE SQL string and runs the query.

<?php

$builder->truncate();
/*
 * Produce:
 * TRUNCATE mytable
 */

Note

If the TRUNCATE command isn’t available, truncate() will execute as “DELETE FROM table”.

Conditional Statements

When

$builder->when()

Added in version 4.3.0.

This allows modifying the query based on a condition without breaking out of the query builder chain. The first parameter is the condition, and it should evaluate to a boolean. The second parameter is a callable that will be ran when the condition is true.

For example, you might only want to apply a given WHERE statement based on the value sent within an HTTP request:

<?php

$status = service('request')->getPost('status');

$users = $this->db->table('users')
    ->when($status, static function ($query, $status) {
        $query->where('status', $status);
    })
    ->get();

Since the condition is evaluated as true, the callable will be called. The value set in the condition will be passed as the second parameter to the callable so it can be used in the query.

Sometimes you might want to apply a different statement if the condition evaluates to false. This can be accomplished by providing a second closure:

<?php

$onlyInactive = service('request')->getPost('return_inactive');

$users = $this->db->table('users')
    ->when($onlyInactive, static function ($query, $onlyInactive) {
        $query->where('status', 'inactive');
    }, static function ($query) {
        $query->where('status', 'active');
    })
    ->get();

WhenNot

$builder->whenNot()

Added in version 4.3.0.

This works exactly the same way as $builder->when() except that it will only run the callable when the condition evaluates to false, instead of true like when().

<?php

$status = service('request')->getPost('status');

$users = $this->db->table('users')
    ->whenNot($status, static function ($query, $status) {
        $query->where('active', 0);
    })
    ->get();

Method Chaining

Method chaining allows you to simplify your syntax by connecting multiple methods. Consider this example:

<?php

$query = $builder->select('title')
    ->where('id', $id)
    ->limit(10, 20)
    ->get();

Resetting Query Builder

ResetQuery

$builder->resetQuery()

Resetting Query Builder allows you to start fresh with your query without executing it first using a method like $builder->get() or $builder->insert().

This is useful in situations where you are using Query Builder to generate SQL (e.g., $builder->getCompiledSelect()) but then choose to, for instance, run the query:

<?php

// Note that the parameter of the `getCompiledSelect()` method is false
$sql = $builder->select(['field1', 'field2'])
    ->where('field3', 5)
    ->getCompiledSelect(false);

// ...
// Do something crazy with the SQL code... like add it to a cron script for
// later execution or something...
// ...

$data = $builder->get()->getResultArray();
/*
 * Would execute and return an array of results of the following query:
 * SELECT field1, field2 FROM mytable WHERE field3 = 5;
 */

Class Reference

class CodeIgniter\Database\BaseBuilder
db()
Returns:

The database connection in use

Return type:

ConnectionInterface

Returns the current database connection from $db. Useful for accessing ConnectionInterface methods that are not directly available to the Query Builder, like insertID() or errors().

resetQuery()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Resets the current Query Builder state. Useful when you want to build a query that can be cancelled under certain conditions.

countAllResults([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset values for SELECTs

Returns:

Number of rows in the query result

Return type:

int

Generates a platform-specific query string that counts all records returned by an Query Builder query.

countAll([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset values for SELECTs

Returns:

Number of rows in the query result

Return type:

int

Generates a platform-specific query string that counts all records in the particular table.

get([$limit = null[, $offset = null[, $reset = true]]]])
Parameters:
  • $limit (int) – The LIMIT clause

  • $offset (int) – The OFFSET clause

  • $reset (bool) – Do we want to clear query builder values?

Returns:

\CodeIgniter\Database\ResultInterface instance (method chaining)

Return type:

\CodeIgniter\Database\ResultInterface

Compiles and runs SELECT statement based on the already called Query Builder methods.

getWhere([$where = null[, $limit = null[, $offset = null[, $reset = true]]]]])
Parameters:
  • $where (string) – The WHERE clause

  • $limit (int) – The LIMIT clause

  • $offset (int) – The OFFSET clause

  • $reset (bool) – Do we want to clear query builder values?

Returns:

\CodeIgniter\Database\ResultInterface instance (method chaining)

Return type:

\CodeIgniter\Database\ResultInterface

Same as get(), but also allows the WHERE to be added directly.

select([$select = '*'[, $escape = null]])
Parameters:
  • $select (array|RawSql|string) – The SELECT portion of a query

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT clause to a query.

selectAvg([$select = ''[, $alias = '']])
Parameters:
  • $select (string) – Field to compute the average of

  • $alias (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT AVG(field) clause to a query.

selectMax([$select = ''[, $alias = '']])
Parameters:
  • $select (string) – Field to compute the maximum of

  • $alias (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT MAX(field) clause to a query.

selectMin([$select = ''[, $alias = '']])
Parameters:
  • $select (string) – Field to compute the minimum of

  • $alias (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT MIN(field) clause to a query.

selectSum([$select = ''[, $alias = '']])
Parameters:
  • $select (string) – Field to compute the sum of

  • $alias (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT SUM(field) clause to a query.

selectCount([$select = ''[, $alias = '']])
Parameters:
  • $select (string) – Field to compute the average of

  • $alias (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a SELECT COUNT(field) clause to a query.

selectSubquery(BaseBuilder $subquery, string $as)
Parameters:
  • $subquery (string) – Instance of BaseBuilder

  • $as (string) – Alias for the resulting value name

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a subquery to the selection

distinct([$val = true])
Parameters:
  • $val (bool) – Desired value of the “distinct” flag

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Sets a flag which tells the query builder to add a DISTINCT clause to the SELECT portion of the query.

from($from[, $overwrite = false])
Parameters:
  • $from (mixed) – Table name(s); string or array

  • $overwrite (bool) – Should we remove the first table existing?

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Specifies the FROM clause of a query.

fromSubquery($from, $alias)
Parameters:
  • $from (BaseBuilder) – Instance of the BaseBuilder class

  • $alias (string) – Subquery alias

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Specifies the FROM clause of a query using a subquery.

setQueryAsData($query[, $alias[, $columns = null]])

Added in version 4.3.0.

Parameters:
  • $query (BaseBuilder|RawSql) – Instance of the BaseBuilder or RawSql

  • $alias (string|null) – Alias for query

  • $columns (array|string|null) – Array or comma delimited string of columns in the query

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Sets a query as a datasource for insertBatch(), updateBatch(), upsertBatch(). If $columns is null the query will be run to generate column names.

join($table, $cond[, $type = ''[, $escape = null]])
Parameters:
  • $table (string) – Table name to join

  • $cond (string|RawSql) – The JOIN ON condition

  • $type (string) – The JOIN type

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a JOIN clause to a query. Since v4.2.0, RawSql can be used as the JOIN ON condition. See also $builder->join().

where($key[, $value = null[, $escape = null]])
Parameters:
  • $key (array|RawSql|string) – Name of field to compare, or associative array

  • $value (mixed) – If a single key, compared to this value

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates the WHERE portion of the query. Separates multiple calls with AND.

orWhere($key[, $value = null[, $escape = null]])
Parameters:
  • $key (mixed) – Name of field to compare, or associative array

  • $value (mixed) – If a single key, compared to this value

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates the WHERE portion of the query. Separates multiple calls with OR.

orWhereIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – The field to search

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a WHERE field IN('item', 'item') SQL query, joined with OR if appropriate.

orWhereNotIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – The field to search

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a WHERE field NOT IN('item', 'item') SQL query, joined with OR if appropriate.

whereIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – Name of field to examine

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a WHERE field IN('item', 'item') SQL query, joined with AND if appropriate.

whereNotIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – Name of field to examine

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a WHERE field NOT IN('item', 'item') SQL query, joined with AND if appropriate.

groupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression, using AND for the conditions inside it.

orGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression, using OR for the conditions inside it.

notGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression, using AND NOT for the conditions inside it.

orNotGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression, using OR NOT for the conditions inside it.

groupEnd()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Ends a group expression.

like($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (array|RawSql|string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a LIKE clause to a query, separating multiple calls with AND.

orLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a LIKE clause to a query, separating multiple class with OR.

notLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a NOT LIKE clause to a query, separating multiple calls with AND.

orNotLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a NOT LIKE clause to a query, separating multiple calls with OR.

having($key[, $value = null[, $escape = null]])
Parameters:
  • $key (mixed) – Identifier (string) or associative array of field/value pairs

  • $value (string) – Value sought if $key is an identifier

  • $escape (string) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a HAVING clause to a query, separating multiple calls with AND.

orHaving($key[, $value = null[, $escape = null]])
Parameters:
  • $key (mixed) – Identifier (string) or associative array of field/value pairs

  • $value (string) – Value sought if $key is an identifier

  • $escape (string) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a HAVING clause to a query, separating multiple calls with OR.

orHavingIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – The field to search

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a HAVING field IN(‘item’, ‘item’) SQL query, joined with OR if appropriate.

orHavingNotIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – The field to search

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a HAVING field NOT IN('item', 'item') SQL query, joined with OR if appropriate.

havingIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – Name of field to examine

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a HAVING field IN('item', 'item') SQL query, joined with AND if appropriate.

havingNotIn([$key = null[, $values = null[, $escape = null]]])
Parameters:
  • $key (string) – Name of field to examine

  • $values (array|BaseBulder|Closure) – Array of target values, or anonymous function for subquery

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Generates a HAVING field NOT IN('item', 'item') SQL query, joined with AND if appropriate.

havingLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a LIKE clause to a HAVING part of the query, separating multiple calls with AND.

orHavingLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a LIKE clause to a HAVING part of the query, separating multiple class with OR.

notHavingLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

  • $insensitiveSearch (bool) – Whether to force a case-insensitive search

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a NOT LIKE clause to a HAVING part of the query, separating multiple calls with AND.

orNotHavingLike($field[, $match = ''[, $side = 'both'[, $escape = null[, $insensitiveSearch = false]]]])
Parameters:
  • $field (string) – Field name

  • $match (string) – Text portion to match

  • $side (string) – Which side of the expression to put the ‘%’ wildcard on

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a NOT LIKE clause to a HAVING part of the query, separating multiple calls with OR.

havingGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression for HAVING clause, using AND for the conditions inside it.

orHavingGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression for HAVING clause, using OR for the conditions inside it.

notHavingGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression for HAVING clause, using AND NOT for the conditions inside it.

orNotHavingGroupStart()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Starts a group expression for HAVING clause, using OR NOT for the conditions inside it.

havingGroupEnd()
Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Ends a group expression for HAVING clause.

groupBy($by[, $escape = null])
Parameters:
  • $by (mixed) – Field(s) to group by; string or array

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a GROUP BY clause to a query.

orderBy($orderby[, $direction = ''[, $escape = null]])
Parameters:
  • $orderby (string) – Field to order by

  • $direction (string) – The order requested - ASC, DESC or random

  • $escape (bool) – Whether to escape values and identifiers

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds an ORDER BY clause to a query.

limit($value[, $offset = 0])
Parameters:
  • $value (int) – Number of rows to limit the results to

  • $offset (int) – Number of rows to skip

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds LIMIT and OFFSET clauses to a query.

offset($offset)
Parameters:
  • $offset (int) – Number of rows to skip

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds an OFFSET clause to a query.

union($union)
Parameters:
  • $union (BaseBulder|Closure) – Union query

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a UNION clause.

unionAll($union)
Parameters:
  • $union (BaseBulder|Closure) – Union query

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds a UNION ALL clause.

set($key[, $value = ''[, $escape = null]])
Parameters:
  • $key (mixed) – Field name, or an array of field/value pairs

  • $value (mixed) – Field value, if $key is a single field

  • $escape (bool) – Whether to escape values

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds field/value pairs to be passed later to insert(), update() or replace().

insert([$set = null[, $escape = null]])
Parameters:
  • $set (array) – An associative array of field/value pairs

  • $escape (bool) – Whether to escape values

Returns:

true on success, false on failure

Return type:

bool

Compiles and executes an INSERT statement.

insertBatch([$set = null[, $escape = null[, $batch_size = 100]]])
Parameters:
  • $set (array) – Data to insert

  • $escape (bool) – Whether to escape values

  • $batch_size (int) – Count of rows to insert at once

Returns:

Number of rows inserted or false on failure

Return type:

int|false

Compiles and executes batch INSERT statements.

Note

When more than $batch_size rows are provided, multiple INSERT queries will be executed, each trying to insert up to $batch_size rows.

setInsertBatch($key[, $value = ''[, $escape = null]])

Deprecated since version 4.3.0: Use CodeIgniter\Database\BaseBuilder::setData() instead.

Parameters:
  • $key (mixed) – Field name or an array of field/value pairs

  • $value (string) – Field value, if $key is a single field

  • $escape (bool) – Whether to escape values

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

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

Important

This method is deprecated. It will be removed in future releases.

upsert([$set = null[, $escape = null]])
Parameters:
  • $set (array) – An associative array of field/value pairs

  • $escape (bool) – Whether to escape values

Returns:

true on success, false on failure

Return type:

bool

Compiles and executes an UPSERT statement.

upsertBatch([$set = null[, $escape = null[, $batch_size = 100]]])
Parameters:
  • $set (array) – Data to upsert

  • $escape (bool) – Whether to escape values

  • $batch_size (int) – Count of rows to upsert at once

Returns:

Number of rows upserted or false on failure

Return type:

int|false

Compiles and executes batch UPSERT statements.

Note

MySQL uses ON DUPLICATE KEY UPDATE, the affected-rows value per row is 1 if the row is inserted as a new row, 2 if an existing row is updated, and 0 if an existing row is set to its current values.

Note

When more than $batch_size rows are provided, multiple UPSERT queries will be executed, each trying to upsert up to $batch_size rows.

update([$set = null[, $where = null[, $limit = null]]])
Parameters:
  • $set (array) – An associative array of field/value pairs

  • $where (string) – The WHERE clause

  • $limit (int) – The LIMIT clause

Returns:

true on success, false on failure

Return type:

bool

Compiles and executes an UPDATE statement.

updateBatch([$set = null[, $constraints = null[, $batchSize = 100]]])
Parameters:
  • $set (array|object|null) – Field name, or an associative array of field/value pairs

  • $constraints (array|RawSql|string|null) – The field or fields used as keys to update on.

  • $batchSize (int) – Count of conditions to group in a single query

Returns:

Number of rows updated or false on failure

Return type:

int|false

Note

Since v4.3.0, the types of the parameters $set and $constraints have changed.

Compiles and executes batch UPDATE statements. The $constraints parameter takes a comma delimited string of columns, an array, an associative array, or RawSql.

Note

When more than $batchSize field/value pairs are provided, multiple queries will be executed, each handling up to $batchSize field/value pairs. If we set $batchSize to 0, then all field/value pairs will be executed in one query.

updateFields($set[, $addToDefault = false[, $ignore = null]])

Added in version 4.3.0.

Parameters:
  • $set (mixed) – Row of columns or array of rows, a row is an array or object

  • $addToDefault (bool) – Adds an additional column than those in dataset

  • $ignore (bool) – An array of columns to ignore from those in $set

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Used with updateBatch() and upsertBatch() methods. This defines the fields which will be updated.

onConstraint($set)

Added in version 4.3.0.

Parameters:
  • $set (mixed) – A set of fields or field used has keys or constraints

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Used with updateBatch() and upsertBatch() methods. This takes a comma delimited string of columns, and array, associative array, or RawSql.

setData($set[, $escape = null[, $alias = '']])

Added in version 4.3.0.

Parameters:
  • $set (mixed) – Row of columns or array of rows, a row is an array or object

  • $escape (bool) – Whether to escape values

  • $alias (bool) – A table alias for dataset

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Used for *Batch() methods to set data for insert, update, upsert.

setUpdateBatch($key[, $value = ''[, $escape = null]])

Deprecated since version 4.3.0: Use CodeIgniter\Database\BaseBuilder::setData() instead.

Parameters:
  • $key (mixed) – Field name or an array of field/value pairs

  • $value (string) – Field value, if $key is a single field

  • $escape (bool) – Whether to escape values

Returns:

BaseBuilder instance (method chaining)

Return type:

BaseBuilder

Adds field/value pairs to be updated in a table later via updateBatch().

Important

This method is deprecated. It will be removed in future releases.

replace([$set = null])
Parameters:
  • $set (array) – An associative array of field/value pairs

Returns:

true on success, false on failure

Return type:

bool

Compiles and executes a REPLACE statement.

delete([$where = ''[, $limit = null[, $reset_data = true]]])
Parameters:
  • $where (string) – The WHERE clause

  • $limit (int) – The LIMIT clause

  • $reset_data (bool) – true to reset the query “write” clause

Returns:

BaseBuilder instance (method chaining) or false on failure

Return type:

BaseBuilder|false

Compiles and executes a DELETE query.

deleteBatch([$set = null[, $constraints = null[, $batchSize = 100]]])
Parameters:
  • $set (array|object|null) – Field name, or an associative array of field/value pairs

  • $constraints (array|RawSql|string|null) – The field or fields used as keys to delete on.

  • $batchSize (int) – Count of conditions to group in a single query

Returns:

Number of rows deleted or false on failure

Return type:

int|false

Compiles and executes batch DELETE query.

increment($column[, $value = 1])
Parameters:
  • $column (string) – The name of the column to increment

  • $value (int) – The amount to increment in the column

Increments the value of a field by the specified amount. If the field is not a numeric field, like a VARCHAR, it will likely be replaced with $value.

decrement($column[, $value = 1])
Parameters:
  • $column (string) – The name of the column to decrement

  • $value (int) – The amount to decrement in the column

Decrements the value of a field by the specified amount. If the field is not a numeric field, like a VARCHAR, it will likely be replaced with $value.

truncate()
Returns:

true on success, false on failure, string on test mode

Return type:

bool|string

Executes a TRUNCATE statement on a table.

Note

If the database platform in use doesn’t support TRUNCATE, a DELETE statement will be used instead.

emptyTable()
Returns:

true on success, false on failure

Return type:

bool

Deletes all records from a table via a DELETE statement.

getCompiledSelect([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset the current QB values or not

Returns:

The compiled SQL statement as a string

Return type:

string

Compiles a SELECT statement and returns it as a string.

getCompiledInsert([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset the current QB values or not

Returns:

The compiled SQL statement as a string

Return type:

string

Compiles an INSERT statement and returns it as a string.

getCompiledUpdate([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset the current QB values or not

Returns:

The compiled SQL statement as a string

Return type:

string

Compiles an UPDATE statement and returns it as a string.

getCompiledDelete([$reset = true])
Parameters:
  • $reset (bool) – Whether to reset the current QB values or not

Returns:

The compiled SQL statement as a string

Return type:

string

Compiles a DELETE statement and returns it as a string.