DQL stands for **D**octrine **Q**uery **L**anguage and is an Object
Query Language derivate that is very similar to the **H**ibernate
**Q**uery **L**anguage (HQL) or the **J**ava **P**ersistence
**Q**uery **L**anguage (JPQL).
In essence, DQL provides powerful querying capabilities over your
object model. Imagine all your objects lying around in some storage
(like an object database). When writing DQL queries, think about
querying that storage to pick a certain subset of your objects.
**CAUTION** A common mistake for beginners is to mistake DQL for
being just some form of SQL and therefore trying to use table names
and column names or join arbitrary tables together in a query. You
need to think about DQL as a query language for your object model,
not for your relational schema.
DQL is case in-sensitive, except for namespace, class and field
names, which are case sensitive.
Types of DQL queries
--------------------
DQL as a query language has SELECT, UPDATE and DELETE constructs
that map to their corresponding SQL statement types. INSERT
statements are not allowed in DQL, because entities and their
relations have to be introduced into the persistence context
through ``EntityManager#persist()`` to ensure consistency of your
object model.
DQL SELECT statements are a very powerful way of retrieving parts
of your domain model that are not accessible via associations.
Additionally they allow to retrieve entities and their associations
in one single sql select statement which can make a huge difference
in performance in contrast to using several queries.
DQL UPDATE and DELETE statements offer a way to execute bulk
changes on the entities of your domain model. This is often
necessary when you cannot load all the affected entities of a bulk
update into memory.
SELECT queries
--------------
DQL SELECT clause
~~~~~~~~~~~~~~~~~
The select clause of a DQL query specifies what appears in the
query result. The composition of all the expressions in the select
clause also influences the nature of the query result.
Here is an example that selects all users with an age > 20:
::
<?php
$query = $em->createQuery('SELECT u FROM MyProject\Model\User u WHERE u.age > 20');
$users = $query->getResult();
Lets examine the query:
-``u`` is a so called identification variable or alias that
refers to the ``MyProject\Model\User`` class. By placing this alias
in the SELECT clause we specify that we want all instances of the
User class that are matched by this query appear in the query
result.
- The FROM keyword is always followed by a fully-qualified class
name which in turn is followed by an identification variable or
alias for that class name. This class designates a root of our
query from which we can navigate further via joins (explained
later) and path expressions.
- The expression ``u.age`` in the WHERE clause is a path
expression. Path expressions in DQL are easily identified by the
use of the '.' operator that is used for constructing paths. The
path expression ``u.age`` refers to the ``age`` field on the User
class.
The result of this query would be a list of User objects where all
users are older than 20.
The SELECT clause allows to specify both class identification
variables that signal the hydration of a complete entity class or
just fields of the entity using the syntax ``u.name``. Combinations
of both are also allowed and it is possible to wrap both fields and
identification values into aggregation and DQL functions. Numerical
fields can be part of computations using mathematical operations.
See the sub-section on
`DQL Functions, Aggregates and Operations <#dqlfn>`_ on more
information.
Joins
~~~~~
A SELECT query can contain joins. There are 2 types of JOINs:
"Regular" Joins and "Fetch" Joins.
**Regular Joins**: Used to limit the results and/or compute
aggregate values.
**Fetch Joins**: In addition to the uses of regular joins: Used to
fetch related entities and include them in the hydrated result of a
query.
There is no special DQL keyword that distinguishes a regular join
from a fetch join. A join (be it an inner or outer join) becomes a
"fetch join" as soon as fields of the joined entity appear in the
SELECT part of the DQL query outside of an aggregate function.
Otherwise its a "regular join".
Example:
Regular join of the address:
::
<?php
$query = $em->createQuery("SELECT u FROM User u JOIN u.address a WHERE a.city = 'Berlin'");
$users = $query->getResult();
Fetch join of the address:
::
<?php
$query = $em->createQuery("SELECT u, a FROM User u JOIN u.address a WHERE a.city = 'Berlin'");
$users = $query->getResult();
When Doctrine hydrates a query with fetch-join it returns the class
in the FROM clause on the root level of the result array. In the
previous example an array of User instances is returned and the
address of each user is fetched and hydrated into the
``User#address`` variable. If you access the address Doctrine does
not need to lazy load the association with another query.
**NOTE** Doctrine allows you to walk all the associations between
all the objects in your domain model. Objects that were not already
loaded from the database are replaced with lazy load proxy
instances. Non-loaded Collections are also replaced by lazy-load
instances that fetch all the contained objects upon first access.
However relying on the lazy-load mechanism leads to many small
queries executed against the database, which can significantly
affect the performance of your application. **Fetch Joins** are the
solution to hydrate most or all of the entities that you need in a
single SELECT query.
Named and Positional Parameters
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
DQL supports both named and positional parameters, however in
contrast to many SQL dialects positional parameters are specified
with numbers, for example "?1", "?2" and so on. Named parameters
are specified with ":name1", ":name2" and so on.
DQL SELECT Examples
~~~~~~~~~~~~~~~~~~~
This section contains a large set of DQL queries and some
explanations of what is happening. The actual result also depends
on the hydration mode.
Hydrate all User entities:
::
<?php
$query = $em->createQuery('SELECT u FROM MyProject\Model\User u');
$users = $query->getResult(); // array of User objects
Retrieve the IDs of all CmsUsers:
::
<?php
$query = $em->createQuery('SELECT u.id FROM CmsUser u');
$ids = $query->getResult(); // array of CmsUser ids
Retrieve the IDs of all users that have written an article:
::
<?php
$query = $em->createQuery('SELECT DISTINCT u.id FROM CmsArticle a JOIN a.user u');
$ids = $query->getResult(); // array of CmsUser ids
Retrieve all articles and sort them by the name of the articles
users instance:
::
<?php
$query = $em->createQuery('SELECT a FROM CmsArticle a JOIN a.user u ORDER BY u.name ASC');
$articles = $query->getResult(); // array of CmsArticle objects
Retrieve the Username and Name of a CmsUser:
::
<?php
$query = $em->createQuery('SELECT u.username, u.name FROM CmsUser u');
$users = $query->getResults(); // array of CmsUser username and id values
echo $users[0]['username'];
Retrieve a ForumUser and his single associated entity:
::
<?php
$query = $em->createQuery('SELECT u, a FROM ForumUser u JOIN u.avatar a');
$users = $query->getResult(); // array of ForumUser objects with the avatar association loaded
echo get_class($users[0]->getAvatar());
Retrieve a CmsUser and fetch join all the phonenumbers he has:
::
<?php
$query = $em->createQuery('SELECT u, p FROM CmsUser u JOIN u.phonenumbers p');
$users = $query->getResult(); // array of CmsUser objects with the phonenumbers association loaded
$phonenumbers = $users[0]->getPhonenumbers();
Hydrate a result in Ascending:
::
<?php
$query = $em->createQuery('SELECT u FROM ForumUser u ORDER BY u.id ASC');
$users = $query->getResult(); // array of ForumUser objects
Or in Descending Order:
::
<?php
$query = $em->createQuery('SELECT u FROM ForumUser u ORDER BY u.id DESC');
$users = $query->getResult(); // array of ForumUser objects
Using Aggregate Functions:
::
<?php
$query = $em->createQuery('SELECT COUNT(u.id) FROM Entities\User u');
$count = $query->getSingleScalarResult();
With WHERE Clause and Positional Parameter:
::
<?php
$query = $em->createQuery('SELECT u FROM ForumUser u WHERE u.id = ?1');
$users = $query->getResult(); // array of ForumUser objects
With WHERE Clause and Named Parameter:
::
<?php
$query = $em->createQuery('SELECT u FROM ForumUser u WHERE u.username = :name');
$users = $query->getResult(); // array of ForumUser objects
With Nested Conditions in WHERE Clause:
::
<?php
$query = $em->createQuery('SELECT u from ForumUser u WHERE (u.username = :name OR u.username = :name2) AND u.id = :id');
$users = $query->getResult(); // array of ForumUser objects
With COUNT DISTINCT:
::
<?php
$query = $em->createQuery('SELECT COUNT(DISTINCT u.name) FROM CmsUser');
$users = $query->getResult(); // array of ForumUser objects
With Arithmetic Expression in WHERE clause:
::
<?php
$query = $em->createQuery('SELECT u FROM CmsUser u WHERE ((u.id + 5000) * u.id + 3) < 10000000');
$users = $query->getResult(); // array of ForumUser objects
Using a LEFT JOIN to hydrate all user-ids and optionally associated
article-ids:
::
<?php
$query = $em->createQuery('SELECT u.id, a.id as article_id FROM CmsUser u LEFT JOIN u.articles a');
$results = $query->getResult(); // array of user ids and every article_id for each user
Restricting a JOIN clause by additional conditions:
::
<?php
$query = $em->createQuery("SELECT u FROM CmsUser u LEFT JOIN u.articles a WITH a.topic LIKE '%foo%'");
$users = $query->getResult();
Using several Fetch JOINs:
::
<?php
$query = $em->createQuery('SELECT u, a, p, c FROM CmsUser u JOIN u.articles a JOIN u.phonenumbers p JOIN a.comments c');
$users = $query->getResult();
BETWEEN in WHERE clause:
::
<?php
$query = $em->createQuery('SELECT u.name FROM CmsUser u WHERE u.id BETWEEN ?1 AND ?2');
$usernames = $query->getResult();
DQL Functions in WHERE clause:
::
<?php
$query = $em->createQuery("SELECT u.name FROM CmsUser u WHERE TRIM(u.name) = 'someone'");
$usernames = $query->getResult();
IN() Expression:
::
<?php
$query = $em->createQuery('SELECT u.name FROM CmsUser u WHERE u.id IN(46)');
$usernames = $query->getResult();
$query = $em->createQuery('SELECT u FROM CmsUser u WHERE u.id IN (1, 2)');
$users = $query->getResult();
$query = $em->createQuery('SELECT u FROM CmsUser u WHERE u.id NOT IN (1)');
$users = $query->getResult();
CONCAT() DQL Function:
::
<?php
$query = $em->createQuery("SELECT u.id FROM CmsUser u WHERE CONCAT(u.name, 's') = ?1");
$ids = $query->getResult();
$query = $em->createQuery('SELECT CONCAT(u.id, u.name) FROM CmsUser u WHERE u.id = ?1');
$idUsernames = $query->getResult();
EXISTS in WHERE clause with correlated Subquery
::
<?php
$query = $em->createQuery('SELECT u.id FROM CmsUser u WHERE EXISTS (SELECT p.phonenumber FROM CmsPhonenumber p WHERE p.user = u.id)');
$ids = $query->getResult();
Get all users who are members of $group.
::
<?php
$query = $em->createQuery('SELECT u.id FROM CmsUser u WHERE :groupId MEMBER OF u.groups');
$query->setParameter(':groupId', $group);
$ids = $query->getResult();
Get all users that have more than 1 phonenumber
::
<?php
$query = $em->createQuery('SELECT u FROM CmsUser u WHERE SIZE(u.phonenumbers) > 1');
$users = $query->getResult();
Get all users that have no phonenumber
::
<?php
$query = $em->createQuery('SELECT u FROM CmsUser u WHERE u.phonenumbers IS EMPTY');
$users = $query->getResult();
Get all instances of a specific type, for use with inheritance
hierarchies:
::
<?php
$query = $em->createQuery('SELECT u FROM Doctrine\Tests\Models\Company\CompanyPerson u WHERE u INSTANCE OF Doctrine\Tests\Models\Company\CompanyEmployee');
$query = $em->createQuery('SELECT u FROM Doctrine\Tests\Models\Company\CompanyPerson u WHERE u INSTANCE OF ?1');
$query = $em->createQuery('SELECT u FROM Doctrine\Tests\Models\Company\CompanyPerson u WHERE u NOT INSTANCE OF ?1');
Partial Object Syntax
^^^^^^^^^^^^^^^^^^^^^
By default when you run a DQL query in Doctrine and select only a
subset of the fields for a given entity, you do not receive objects
back. Instead, you receive only arrays as a flat rectangular result
set, similar to how you would if you were just using SQL directly
and joining some data.
If you want to select partial objects you can use the ``partial``
DQL keyword:
::
<?php
$query = $em->createQuery('SELECT partial u.{id, username} FROM CmsUser u');
$users = $query->getResult(); // array of partially loaded CmsUser objects
You use the partial syntax when joining as well:
::
<?php
$query = $em->createQuery('SELECT partial u.{id, username}, partial a.{id, name} FROM CmsUser u JOIN u.articles a');
$users = $query->getResult(); // array of partially loaded CmsUser objects
Using INDEX BY
~~~~~~~~~~~~~~
The INDEX BY construct is nothing that directly translates into SQL
but that affects object and array hydration. After each FROM and
JOIN clause you specify by which field this class should be indexed
in the result. By default a result is incremented by numerical keys
starting with 0. However with INDEX BY you can specify any other
column to be the key of your result, it really only makes sense
CREATE TABLE Person (id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, name VARCHAR(50) NOT NULL, discr VARCHAR(255) NOT NULL, department VARCHAR(50) NOT NULL)
Now when persist a new ``Employee`` instance it will set the
discriminator value for us automatically:
::
<?php
$employee = new \Entities\Employee();
$employee->setName('test');
$employee->setDepartment('testing');
$em->persist($employee);
$em->flush();
Now lets run a simple query to retrieve the ``Employee`` we just
SELECT p0_.id AS id0, p0_.name AS name1, p0_.department AS department2, p0_.discr AS discr3 FROM Person p0_ WHERE (p0_.name = ?) AND p0_.discr IN ('employee')
SELECT p0_.id AS id0, p0_.name AS name1, e1_.department AS department2, p0_.discr AS discr3 FROM Employee e1_ INNER JOIN Person p0_ ON e1_.id = p0_.id WHERE p0_.name = ?
The Query class
---------------
An instance of the ``Doctrine\ORM\Query`` class represents a DQL
query. You create a Query instance be calling
``EntityManager#createQuery($dql)``, passing the DQL query string.
Alternatively you can create an empty ``Query`` instance and invoke
``Query#setDql($dql)`` afterwards. Here are some examples:
::
<?php
// $em instanceof EntityManager
// example1: passing a DQL string
$q = $em->createQuery('select u from MyProject\Model\User u');
// example2: using setDql
$q = $em->createQuery();
$q->setDql('select u from MyProject\Model\User u');
Query Result Formats
~~~~~~~~~~~~~~~~~~~~
The format in which the result of a DQL SELECT query is returned
can be influenced by a so-called ``hydration mode``. A hydration
mode specifies a particular way in which an SQL result set is
transformed. Each hydration mode has its own dedicated method on
the Query class. Here they are:
-``Query#getResult()``: Retrieves a collection of objects. The
result is either a plain collection of objects (pure) or an array
where the objects are nested in the result rows (mixed).
-``Query#getSingleResult()``: Retrieves a single object. If the
result contains more than one object, an exception is thrown. The
pure/mixed distinction does not apply.
-``Query#getArrayResult()``: Retrieves an array graph (a nested
array) that is largely interchangeable with the object graph
generated by ``Query#getResultList()`` for read-only purposes.
**NOTE** An array graph can differ from the corresponding object
graph in certain scenarios due to the difference of the identity
semantics between arrays and objects.
-``Query#getScalarResult()``: Retrieves a flat/rectangular result
set of scalar values that can contain duplicate data. The
pure/mixed distinction does not apply.
-``Query#getSingleScalarResult()``: Retrieves a single scalar
value from the result returned by the dbms. If the result contains
more than a single scalar value, an exception is thrown. The
pure/mixed distinction does not apply.
Instead of using these methods, you can alternatively use the
Using this method you can directly supply the hydration mode as the
second parameter via one of the Query constants. In fact, the
methods mentioned earlier are just convenient shortcuts for the
execute method. For example, the method ``Query#getResultList()``
internally invokes execute, passing in ``Query::HYDRATE_OBJECT`` as
the hydration mode.
The use of the methods mentioned earlier is generally preferred as
it leads to more concise code.
Pure and Mixed Results
~~~~~~~~~~~~~~~~~~~~~~
The nature of a result returned by a DQL SELECT query retrieved
through ``Query#getResult()`` or ``Query#getArrayResult()`` can be
of 2 forms: **pure** and **mixed**. In the previous simple
examples, you already saw a "pure" query result, with only objects.
By default, the result type is **pure** but
**as soon as scalar values, such as aggregate values or other scalar values that do not belong to an entity, appear in the SELECT part of the DQL query, the result becomes mixed**.
A mixed result has a different structure than a pure result in
order to accommodate for the scalar values.
A pure result usually looks like this:
::
array
[0] => Object
[1] => Object
[2] => Object
...
A mixed result on the other hand has the following general
structure:
::
array
array
[0] => Object
[1] => "some scalar string"
['count'] => 42
// ... more scalar values, either indexed numerically or with a name
array
[0] => Object
[1] => "some scalar string"
['count'] => 42
// ... more scalar values, either indexed numerically or with a name
To better understand mixed results, consider the following DQL