Versions Compared

Key

  • This line was added.
  • This line was removed.
  • Formatting was changed.

This document describes how to generate and execute sql queries using a query builder, mostly the builder was modelled of Laravel Query Builder, which already provides quite a thorough documentation, however some methods might be a bit different. Any significant difference will be outlined in this document as a separate paragraph.

Location

ORM and its dependencies is located under \core\orm namespace. The builder itself lives in \core\orm\query Feel free to examine the code.

...

Code Block
themeEmacs
use \core\orm\query\builder;

Example database

For the purpose of any examples in the given document, the following tables will be used:

...

Orders - tbl_orders
iduser_idgoods_item_idquantity
111496
2321
3632
4343
5545
6223

Retrieving results

Retrieving from a table

It's very simple to select results from a table, all the examples following in the document will be selecting records from a table.

Code Block
themeEmacs
// You can instantiate a builder to operate on a table using a factory method "table"
builder::table('table_name')
	->...;

// If you prefer to new up a class in a conventional way, you can do the following:
(new builder())
	->from('table_name', 'optional_alias') // The alias defaults to the table name if not set
	->...;

Retrieving from a subquery

As an alternative to retrieving results from a table, you might select results from a subquery (represented by another builder instance).

Code Block
themeEmacs
$sub_query = builder::table('user', 't1')
    ->where('status', 1);

// You must set an alias for the subquery, otherwise an exception will be thrown
$user = builder::table($sub_query)
    ->as('sq')
    ->where('name', 'like', 'John Doe')
    ->first();

// Alternatively:
$query = new builder();
$user = $query->from($sub_query)
    ->as('sq')
	->where('name', 'like', 'John Doe')
	->first();

// The latter will give you the following SQL (might differ slightly from db to db)
//
// SELECT "sq".* 
// FROM (SELECT * FROM {user} "t1" WHERE status = :p_1) sq 
// WHERE "sq".name LIKE :p_2 
// LIMIT 1; [:p_1 => 1, :p_2 => '%John Doe%']



Retrieve a single row

find(id) / find_or_fail(id)

Returns a single row identified by passed id. If the row does not exist in the table it returns null. It does ignore any other conditions, joins, unions, etc. and always fetches all columns for the row.

...

Section
Column
width50%
Code Block
languagephp
themeEmacs
$user = builder::table('users')->find(1);

// Will throw exception if record is not found
$user = builder::table('users')->find_or_fail(1);
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$user = $DB->get_record('users', ['id' => 1]);

// Will throw exception if record is not found
$user = $DB->get_record('users', ['id' => 1], '*', MUST_EXIST);

first() / first_or_fail()

Returns the first row of the result. You have to specify order_by() if you want to use first(). You cannot use limit() in conjunction with first().

...

Section
Column
width50%
Code Block
languagephp
themeEmacs
$user = builder::table('users')
    ->where('status', 1)
    ->order_by('votes', 'desc')
    ->first();

// Will throw exception if no records found
$user = builder::table('users')
    ->where('name', 'like', 'Bob')
    ->order_by('votes', 'desc')
    ->first_or_fail();
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$user = $DB->get_records('users', ['status' => 1], 'votes DESC', '*', 0, 1);

one()

Returns only one row assuming that the row is unique with given parameters. Will throw an exception if multiple rows exist.  You cannot use offset() or limit() in conjunction with one().

...

Section
Column
width50%
Code Block
languagephp
themeEmacs
$user = builder::table('users')
    ->where('name', 'John Doe')
    ->one();
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$user = $DB->get_record('users', ['name' => 'John Doe']);

Retrieving multiple rows

fetch()

Fetches all rows of the table or if conditions are present, all rows matching the given conditions. By default returns an array of stdClass instances. The type of result can be changed either to an array or any other object by using the map_to() function.

Section
Column
width50%
Code Block
languagephp
themeEmacs
// Returns all results from the table
$users = builder::table('users')->fetch();

$users = builder::table('users')
    ->where('status', 1)
    ->fetch();

// Return an array of arrays
$users = builder:::table('users')
    ->results_as_arrays()
    ->fetch();
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$users = $DB->get_records('users'); 

$users = $DB->get_records('users', ['status' => 1]);

fetch_recordset() / get_lazy()

Returns a lazy_collection instance which extends moodle_recordset. This is useful if you want lazy loading of results. It will reduce the amount of memory used as it only loads one record at a time if you cycle through it. But on the other hand you can't count the results or use other functionality on it.

If you've used map_to() / results_as_arrays() / results_as_objects() in your query to map the items to a custom class, array or stdClass then the lazy_collection will take care of that mapping on each item.

...

Section
Column
width50%
Code Block
languagephp
themeEmacs
$users = builder::table('users')->fetch_recordset();

// Record will be loaded only once accessed
foreach ($users as $user) {
    echo $user->name;
}
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$users = $DB->get_recordset('users');

// Record will be loaded only once accessed
foreach ($users as $user) {
    echo $user->name;
}

fetch_counted()

Returns the results and the total amount of items of your query.

Section
Column
width50%
Code Block
languagephp
themeEmacs
[$users, $count] = builder::table('users')
    ->where('status', 1)
    ->offset(0)
    ->limit(5)
    ->fetch_counted();

echo "$count users found.";  // 7 users found.

// Example: will output the first 5 active users
foreach ($users as $user) {
    echo $user->name;
}
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$sql = "SELECT * FROM {users} WHERE status = :status";
$count = 0; 

$users = $DB->get_counted_records_sql($sql, ['status' => 1], 0, 5, $count);

echo "$count users found.";

foreach ($users as $user) {
    echo $user->name;
}

get()

Alternative to fetch(). Always returns a collection instead of an array.

...

Code Block
languagephp
themeEmacs
$users = builder::table('users')->get();

paginate()

This function retrieves paginated results. It returns a paginator instance which also can be used standalone by passing a builder instance to it.

...

Code Block
languagephp
themeEmacs
// Use paginator class
$query = builder::table('users');
$users = new paginator($query, 1, 5);

// Or use the fluent interface with paginate()
$users = builder::table('users')
    ->paginate(1, 5);

// paginator acts as an iterator so you can foreach over it
foreach ($users as $user) {
    echo $user->name;
}

// Prints: 5
echo $users->count();
// Prints 1
echo $users->get_page();
// Prints: 7
echo $users->get_total();

print_r($users->to_array());

/* prints:

 Array(
     'items' => Array(
         Array(
             'id' => 1,
             'name' => 'John Doe',
             ...
         ),
         ...
     ),
     'page' => 1,   // current page you are on
     'pages' => 2,  // total number of pages
     'items_per_page' => 5, 
     'next' => 1,      // next page number, null on the last page
     'prev' => null,   // previous page number, null on the first page
     'total' => 7  // total number of items
 )

*/

Other functions

value()

Returns the a single value from a record. This method will return the value of the column directly.

Section
Column
width50%
Code Block
languagephp
themeEmacs
$email = builder::table('users')
    ->where('name', 'John Doe')
    ->value('email');
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$email = $DB->get_field('users', 'email', ['name' => 'John Doe']);

count()

Returns the amount of rows for the given query.

Section
Column
width50%
Code Block
languagephp
themeEmacs
$user_amount = builder::table('users')->count();

$user_amount = builder::table('users')
    ->where('status', 1)
    ->count();
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$user_amount = $DB->count_records('users'); 

$user_amount = $DB->count_records('users', ['status' => 1]);

exists() / does_not_exist()

Returns true if the record(s) matching the current query exist / not exist.

Section
Column
width50%
Code Block
languagephp
themeEmacs
$exists = builder::table('users')
    ->where('name', 'John Doe')
    ->exist();

$not_exists = builder::table('users')
    ->where('name', 'John Doe')
    ->or_where('name', 'Jane Doe')
    ->does_not_exist();
Column
width50%
Code Block
languagephp
themeEmacs
titleDML
collapsetrue
$exists = $DB->record_exists('users', ['name' => 'John Doe']);
$select = 'name = :name1 OR name = :name2';
$params = [
    'name1' => 'John Doe',
    'name2' => 'Jane Doe'
];
$not_exists = !$DB->record_exists_select('users', $select, $params);

Selects

Selecting a field

To select items from your database you should use select or add_select method, the first one overrides your sql select statement, the latter one appends. Field names are passed through a standard regex check to help you against sql injections.

Will give you the following result:

id

name

1

John Doe

Selecting aggregates

Sometimes you need to do more complex selects than just a field name, for example using aggregate functions, builder allows for it, treating it as valid column names. Most commonly aggregate functions are supported: MIN, MAX, AVG, SUM, COUNT.

...

min_quantitymax_quantityavg_quantitytotal_quantityorders
1496855106

Selecting subquery

It's possible to use subqueries in select statements as well

...

If this is still not sufficient, then you might resort to the raw versions of the select methods:

Selecting raw statement

When you use select statement the field that you are attempting to select is validated against a regular expression "a-zA-Z-_|*" (it actually is a bit more complex to allow for aliases, aggregate functions and prefixes - more on that later). Sometimes though you might need to use more advanced SQL in select, to achieve it you might use raw methods, raw methods embed provided strings directly into sql statement. Browse Query builder 1 Raw methods to see the list of all available raw methods.

...

idnamecharacter
1John DoeGood

Joins

Inner join

Query builder might join other tables for you. To perform an inner join (or just join for simplification) you may use the join method, the first argument is the name of the table to join, the remaining arguments define the column in the main table, the condition and the column in the table being joined.

...

iduser_idgoods_item_idquantityuser_name
111496John Doe

Left join

To perform a left join use the following construct:

Right join

Full join

Cross join

Cross join is slightly different from all the previous joins as it does not take any arguments, only the table name

Joining multiple tables

You may join multiple tables using the builder, simply call join several times on the builder object.

...

order_iduser_nameitem_namequantity
1John DoeA brick496

Complex condition joins

Sometimes you want to join tables on multiple conditions, this also possible via the builder, you would need to use the following syntax

Alternative syntax

To define a custom alias for a joined table, you may use an alternative syntax for table field:

Sub query join

Subquery joins are possible, you will need to pass a query builder instance or subquery class instance instead of a table name to the join method. An alias must be specified for subquery joins!

Where Clauses

Simple Where Clauses

You can use the where method to add where conditions to your query. Where accepts three arguments:

...

Section
Column
width50%
Code Block
languagephp
themeEmacs
$users = builder::table('users')  
    ->where('status', 1) // defaults to =    
    ->where('id', [3, 4, 5, 6]) // defaults to in()
    ->fetch();
Column
width50%
Code Block
languagephp
titleDML
collapsetrue
list($sql_in, $params) = $DB->get_in_or_equal([3, 4, 5, 6], SQL_PARAMS_NAMED);
$params['status'] = 1;
$users = $DB→get_records_select('users', "status = :status AND id $sql_in", $params);

OR statements

You can chain where clauses as well as add or_ clauses to the query. The or_where function accepts the same arguments as the where function.

Code Block
languagephp
// WHERE name = 'John Doe' OR name = 'Jane Doe'
$users = builder::table('users')
    ->where('name', 'John Doe')
    ->or_where('name', 'Jane Doe')
    ->fetch();

Nested where clauses / Parameter grouping

If you need to group where clauses you can use the nested where functionality. Just pass a Closure argument, which will receive the nested builder as an argument.

Code Block
languagephp
// WHERE status = 1 AND (name = 'John Doe' OR name = 'Jane Doe')
$does = builder::table('users')
    ->where('status', 1)
    ->where(function (builder $builder) {
        $builder->where('name', 'John Doe')
            ->or_where('name', 'Jane Doe')
    })->fetch();

Additional where clauses

where_field / or_where_field

This function allows to compare two columns. Both fields are passed through a standard regex field name check here, that should prevent you from basic sql injections.

Code Block
languagephp
// WHERE last_login = created
$does = builder::table('users')
    ->where_field('last_login', 'created')
    ->fetch();

// WHERE last_login > created
$does = builder::table('users')
    ->where_field('last_login', '>', 'created')
    ->fetch();

where_null / or_where_null / where_not_null / or_where_not_null

This is a shortcut for ->where('column', null);

Code Block
languagephp
// WHERE last_login IS NULL
$does = builder::table('users')
    ->where_null('last_login')
    ->fetch();

// WHERE last_login IS NOT NULL
$does = builder::table('users')
    ->where_not_null('last_login')
    ->fetch();

where_in / or_where_in / where_not_in / or_where_not_in

This is a shortcut for ->where('column', 'in', $value);

where_like / or_where_like / where_like_starts_with / or_where_like_starts_with / where_like_ends_with / or_where_like_ends_with

The builder provides some shortcuts for LIKE statements.

...

If you need NOT LIKE statements use: !like, !like_starts_with, !like_ends_with, !ilike, !ilike_starts_with, !ilike_ends_with

where_like_raw / or_where_like_raw

If none of the other like functions cover you need you can use the raw methods. The value won't be surrounded by any percentage signs, this needs to be handled by yourself.

...

Code Block
languagephp
$does = builder::table('users')
    ->where_like_raw('name', 'John%Doe')
    ->fetch();

where_exists / or_where_exists / where_not_exists / or_where_not_exists

The where_exists functions allows for creating a WHERE EXISTS (subquery) condition. It accepts a builder or a Closure argument, which will receive a new builder instance. This allows you to define the query that should be used inside the exists statement.

Code Block
languagephp
// SELECT * 
// FROM orders
// WHERE EXISTS (SELECT id FROM users WHERE name LIKE '%Doe' AND id = orders.user_id)
$second_builder = builder::table('users')
    ->select('id')
    ->where('name', 'like_ends_with', 'Doe')
    ->where_field('users.id', 'orders.user_id');

$orders = builder::table('orders')
	->where_exists($second_builder)
    ->fetch();

// Alternative
$orders = builder::table('orders')
    ->where_exists(function(builder $builder) {
        $builder->select('id')
            ->where('name', 'like_ends_with', 'Doe')
            ->where_field('users.id', 'orders.user_id');
    })->fetch();

Raw where clauses

If you need to pass a raw condition to your query you can either pass an instance of sql to your clause:

...

Warning

Raw methods embed strings directly into sql query, sql injection protection is required!

Complex example

Section
Column
width50%
Code Block
languagephp
// WHERE (name = 'John Doe' OR name = 'Jane Doe') AND (status = 1 OR last_login IS NULL) AND email LIKE '%gmail.com'
$users = builder::table('users')
    ->where(function (builder $builder) {
        $builder->where('name', 'John Doe')
            ->or_where('name', 'Jane Doe');
    })
    ->where(function (builder $builder) {
        $builder->where('status', 1)
            ->or_where_null('last_login');
    })
    ->where_like_ends_with('email', 'gmail.com')
    ->fetch();
Column
width50%
Code Block
languagephp
titleDML
collapsetrue
$select = "(name = :name1 OR name = :name2) AND (status = :status OR last_login IS NULL) AND $like_sql";
$params = [
    'name1' => 'John Doe',
    'name2' => 'Jane Doe',
    'status' => 1
];

$like_sql = $DB->sql_like('email', ':email');
$params['email'] = '%'.$DB->sql_like_escape('gmail.com');

$users = $DB→get_records_select('users', "status = :status AND id $sql_in", $params);

Order

Order by a column

It's quite easy to add order statements to the query using query builder. To simply order by a column name you should use order_by method.

...

This will give you the following result

idname
2Jane Doe
1John Doe

Order by multiple columns

If you need to order by multiple columns subsequent calls to order_by will achieve that. Each call to order_by appends to order condition sql.

...

Info
titleTODO

Currently it behaves slightly differently from select methods naming wise. Calling select overrides current select sql and calling add_select() appends to it, order_by() doesn't have add_order_by() and appends to the order condition to override it, however it allows you to call do_not_order() to reset order list.

Order by raw statement

Similar to column names passed to select and add_select methods, column names are validated to protect you against accidental sql-injection. However if you require order by raw statement it is achievable calling order_by_raw method

...

You may also use (raw) sql with order_by

Grouping

Group by a column

If you need to group results by a column, builder allows you to do that and there is a group_by method to do that.

...

user_namemax_quantity
John Doe496
Ivan Svobodin5

Group by multiple columns

If you need to group results by multiple columns, builder allows you to do that doing multiple calls to group_by method.

Builders also allows you to reset any order condition added, by calling reset_group_by() method or passing null to the group_by() method.

Group by raw value

If you need some more complex grouping, you may resort to a raw method group_by_raw to embed a raw string into the query. It works in a similar manner to order_by_raw and add_select_raw

Warning

Raw methods embed strings directly into sql query, sql injection protection is required!

Offsetting or limiting the results

limit()

Will add limit to the results

Code Block
languagephp
$users = builder::table('users')
	->limit(1)
	->get();

// Usually used together with limit
$users = builder::table('users')
	->first(); // Calling first will add limit 1 to the query

offset()

Will add offset to the query

...

Warning

Due to the DB driver limitations limits can not be used within any form of subqueries. If you add a limit there, you will get a debugging notice

Unions

The query builder also provides easy means to unite 2 queries together. Here is how it works.

...

idname
1John Doe
2Jane Doe
6Alisson Carr

Field auto-prefixing

Short version:

If you do not specify an alias on your builder then the builder automatically will use the table name (without the prefix) as the alias. You can specify your own alias by using the as() function or pass it as second argument to the builder::table() function.

...

Let's get to some code examples to get better understanding of all this.

Raw methods

In addition to some query building methods query builder offers a raw version which has a suffix '_raw' and accepts 2 arguments: sql and parameters. These methods embed provided sql in the appropriate part of the query

...

Warning

Raw methods embed strings directly into sql query, sql injection protection is required!

Mapping of results

By default all the methods which retrieve results (find, find_or_fail, fetch, get, fetch_recordset, paginate, first, one) will return an instance of stdClass for a single record.

However, you can influence that behaviour and either have records returned as arrays or as any custom objects.

Map to array()

Just call results_as_arrays() anytime before calling one of the methods mentioned above.

Code Block
languagephp
$users = builder::table('users')
    ->results_as_arrays()
    ->fetch();

Map to stdClass

This is the default behaviour which will make sure each record is represented by a stdClass instance.

Code Block
languagephp
$users = builder::table('users')
    ->results_as_objects()
    ->fetch();

Map to custom objects

Use the map_to() function to map to your own objects. The map_to function either accepts a Closure or a class name, which it will create instances of when retrieving the results. It will pass the result from the database as an argument to the Closure or as into the constructor of the given class.

...

You can combine results_as_arrays() and map_to() if you want your custom class accept the record as an array rather than a stdClass instance.

Conditional Clauses

When \ Unless

Sometimes you want to conditionally include clauses in your query.

...

Code Block
languagephp
// if ($only_active) { ... } else { ... }
$users = builder::table('users')
    ->when($only_active, function (builder $builder) {
        $builder->where('status', 1);
    }, function (builder $builder) {
        $builder->where('status', 0);   
    })->fetch();

Tap

Tap is a shortcut for an unconditional when() (->when(true, callable)). You can use this to group your builder statements, or if you are building groups of statements and then joining them together.

Code Block
languagephp
// It might be useful for debugging purposes as well as if you have one fluent flow 
// and you need a builder reference without braking the flow.
$users = builder::table('users')
	->where('status', 1)
    ->where('votes', '>', 50)
    ->tap(function (builder $builder) {
		var_dump($builder);
    })
	->where('name', 'like', 'John')
	->fetch();

Modifying data

The builder can not only be used to retrieve data but also to modify data.

Insert

Use the insert() method to insert new rows into the table. No further conditions or query parts can be used.

Section
Column
width50%
Code Block
languagephp
// You can pass an array
$user = [
    'name' => Jack Doe',
    'status' => 1,
    'password' => 'dfsdf3w2@#@#$WREDSfds',
    'email' => 'jack.doe@gmail.com'
];

builder::table('users')->insert($user);

// You can also pass an instance of stdClass
$user = new stdClass();
$user->name = 'Jack Doe';
$user->status = 1;
$user->password = 'dfsdf3w2@#@#$WREDSfds';
$user->email = 'jack.doe@gmail.com';

$id = builder::table('users')->insert($user);
Column
width50%
Code Block
languagephp
titleDML
collapsetrue
$user = new stdClass();
$user->name = 'Jack Doe';
$user->status = 1;
$user->password = 'dfsdf3w2@#@#$WREDSfds';
$user->email = 'jack.doe@gmail.com';

$id = $DB->insert_record('users', $user);

Update

You can update multiple rows in a table by using the update() method. Please note that update does not accepts an array/object containing an id. If you want to update a single record you can either use the where condition or use update_record()

...

Warning
titleOops

Due to database support limitation, you can use only where part of the query for update statements, if you try to add any joins, you will get an exception, when attempting to execute the query.

Update Record

You can update a single record in two ways, first using →update() in conjunction with a proper where condition or ->update_record().

Section
Column
width50%
Code Block
languagephp
// You can pass an array of fields to update and use where()
$data = [
    'status' => 0,
    'password' => 'reset_password'
];

builder::table('users')
    ->where('id', 1)
    ->update($data);

// Or pass a record containing the id to update_record()
$data = [
    'id' => 1,
    'status' => 0,
    'password' => 'reset_password'
];

builder::table('users')->update_record($data);
Column
width50%
Code Block
languagephp
titleDML
collapsetrue
$data = [
    'id' => 1,
    'status' => 0,
    'password' => 'reset_password'
];

$DB->update_record('users', $data);

Delete

You can delete multiple records in table by using the delete() method.

...

Warning
titleOops

Due to database support limitation, you can use only where part of the query for delete statements, if you try to add any joins, you will get an exception, when attempting to execute the query.

Differences with Laravel's Query Builder

Missing where methods

At this stage we don't have the following methods for some reason or another

  • where_between / or_where_between and where_not_between / or_where_not_between haven't been implemented yet, don't see any reason why not, they should just translate to 2 wheres internally
  • whereDate / whereMonth / whereDay / whereYear / whereTime haven't been implemented, they require some more investigation, due to the fact that they use internal database functions, might be doable with some additions to dml layer.
  • where_column / or_where_column originally implemented as (or_)where_field, we might revisit it, p.s. generally what Laravel refers to as column we refer to as field in quite a lot of places
  • JSON where clauses - require support at the dml level, by the time of writing I believe all database engines we use have built-in json support with a slightly different syntax.

Missing features

  • Change locking type, query builder provides a way to use shared locks \ locks for update, this implementation leaves that out to dml.
  • Increment \ Decrement 2 methods that take field (column) name as argument and increment or decrement a given field respectively according to a given where clause
  • update_or_insert - not implemented yet, it takes 2 arrays as arguments, it uses first to query a record from database and then if not found it inserts it with attributes from both arrays or either if found, it updates the record with attributes from a second array.
  • in_random_order - not implemented, requires support on a dml level, as sql varies slightly from dbms to dbms. To simplify what it does, it adds ORDER BY RANDOM()

Behavioural differences

  • In laravel select and add_select functions take multiple arguments to add multiple columns to select, in the current implementation the functions take one argument either as string/field object or an array of strings / field objects to select multiple fields in one statement.
  • In the current implementation field prefixing is more advanced

...