data-retrieval-and-manipulation.rst 16.4 KB
Newer Older
1 2 3
Data Retrieval And Manipulation
===============================

4
Doctrine DBAL follows the PDO API very closely. If you have worked with PDO
5
before you will get to know Doctrine DBAL very quickly. On top of the API provided
6 7
by PDO there are tons of convenience functions in Doctrine DBAL.

8 9 10
Data Retrieval
--------------

11
Using a database implies retrieval of data. It is the primary use-case of a database.
12
For this purpose each database vendor exposes a Client API that can be integrated into
13
programming languages. PHP has a generic abstraction layer for this
14
kind of API called PDO (PHP Data Objects). However because of disagreements
15 16 17 18
between the PHP community there are often native extensions for each database
vendor that are much more maintained (OCI8 for example).

Doctrine DBAL API builds on top of PDO and integrates native extensions by
19
wrapping them into the PDO API as well. If you already have an open connection
20 21 22 23 24 25
through the ``Doctrine\DBAL\DriverManager::getConnection()`` method you
can start using this API for data retrieval easily.

Start writing an SQL query and pass it to the ``query()`` method of your
connection:

26
.. code-block:: php
27 28 29 30 31 32 33 34 35

    <?php
    use Doctrine\DBAL\DriverManager;

    $conn = DriverManager::getConnection($params, $config);

    $sql = "SELECT * FROM articles";
    $stmt = $conn->query($sql); // Simple, but has several drawbacks

36
The query method executes the SQL and returns a database statement object.
37 38 39
A database statement object can be iterated to retrieve all the rows that matched
the query until there are no more rows:

40 41
.. code-block:: php

42 43 44 45 46 47 48 49 50
    <?php

    while ($row = $stmt->fetch()) {
        echo $row['headline'];
    }

The query method is the most simple one for fetching data, but it also has
several drawbacks:

51
-   There is no way to add dynamic parameters to the SQL query without modifying
52
    ``$sql`` itself. This can easily lead to a category of security
53 54
    holes called **SQL injection**, where a third party can modify the SQL executed 
    and even execute their own queries through clever exploiting of the security hole.
55
-   **Quoting** dynamic parameters for an SQL query is tedious work and requires lots
56 57
    of use of the ``Doctrine\DBAL\Connection#quote()`` method, which makes the
    original SQL query hard to read/understand.
58
-   Databases optimize SQL queries before they are executed. Using the query method
59
    you will trigger the optimization process over and over again, although
60
    it could re-use this information easily using a technique called **prepared statements**.
61 62 63 64 65 66 67 68 69 70 71 72 73 74

This three arguments and some more technical details hopefully convinced you to investigate
prepared statements for accessing your database. 

Dynamic Parameters and Prepared Statements
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

Consider the previous query, now parameterized to fetch only a single article by id.
Using **ext/mysql** (still the primary choice of MySQL access for many developers) you had to escape
every value passed into the query using ``mysql_real_escape_string()`` to avoid SQL injection:

.. code-block:: php

    <?php
75
    $sql = "SELECT * FROM articles WHERE id = '" . mysql_real_escape_string($id, $link) . "'";
76 77 78
    $rs = mysql_query($sql);

If you start adding more and more parameters to a query (for example in UPDATE or INSERT statements)
79
this approach might lead to complex to maintain SQL queries. The reason is simple, the actual
80
SQL query is not clearly separated from the input parameters. Prepared statements separate
81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96
these two concepts by requiring the developer to add **placeholders** to the SQL query (prepare) which
are then replaced by their actual values in a second step (execute).

.. code-block:: php

    <?php
    // $conn instanceof Doctrine\DBAL\Connection

    $sql = "SELECT * FROM articles WHERE id = ?";
    $stmt = $conn->prepare($sql);
    $stmt->bindValue(1, $id);
    $stmt->execute();

Placeholders in prepared statements are either simple positional question marks (?) or named labels starting with
a double-colon (:name1). You cannot mix the positional and the named approach. The approach
using question marks is called positional, because the values are bound in order from left to right
97
to any question mark found in the previously prepared SQL query. That is why you specify the
98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126
position of the variable to bind into the ``bindValue()`` method:

.. code-block:: php

    <?php
    // $conn instanceof Doctrine\DBAL\Connection

    $sql = "SELECT * FROM articles WHERE id = ? AND status = ?";
    $stmt = $conn->prepare($sql);
    $stmt->bindValue(1, $id);
    $stmt->bindValue(2, $status);
    $stmt->execute();

Named parameters have the advantage that their labels can be re-used and only need to be bound once:

.. code-block:: php

    <?php
    // $conn instanceof Doctrine\DBAL\Connection

    $sql = "SELECT * FROM users WHERE name = :name OR username = :name";
    $stmt = $conn->prepare($sql);
    $stmt->bindValue("name", $name);
    $stmt->execute();

The following section describes the API of Doctrine DBAL with regard to prepared statements.

.. note::

127
    Support for positional and named prepared statements varies between the different
128 129 130 131 132 133 134 135 136 137
    database extensions. PDO implements its own client side parser so that both approaches
    are feasible for all PDO drivers. OCI8/Oracle only supports named parameters, but
    Doctrine implements a client side parser to allow positional parameters also.

Using Prepared Statements
~~~~~~~~~~~~~~~~~~~~~~~~~

There are three low-level methods on ``Doctrine\DBAL\Connection`` that allow you to
use prepared statements:

138
-   ``prepare($sql)`` - Create a prepared statement of the type ``Doctrine\DBAL\Statement``.
139
    Using this method is preferred if you want to re-use the statement to execute several
140
    queries with the same SQL statement only with different parameters.
141
-   ``executeQuery($sql, $params, $types)`` - Create a prepared statement for the passed
142
    SQL query, bind the given params with their binding types and execute the query.
143 144
    This method returns the executed prepared statement for iteration and is useful
    for SELECT statements.
145
-   ``executeUpdate($sql, $params, $types)`` - Create a prepared statement for the passed
146
    SQL query, bind the given params with their binding types and execute the query.
147 148 149 150 151 152 153 154
    This method returns the number of affected rows by the executed query and is useful
    for UPDATE, DELETE and INSERT statements.

A simple usage of prepare was shown in the previous section, however it is useful to
dig into the features of a ``Doctrine\DBAL\Statement`` a little bit more. There are essentially
two different types of methods available on a statement. Methods for binding parameters and types
and methods to retrieve data from a statement.

155
-   ``bindValue($pos, $value, $type)`` - Bind a given value to the positional or named parameter
156
    in the prepared statement.
157
-   ``bindParam($pos, &$param, $type)`` - Bind a given reference to the positional or
158 159 160 161 162 163
    named parameter in the prepared statement.

If you are finished with binding parameters you have to call ``execute()`` on the statement, which
will trigger a query to the database. After the query is finished you can access the results
of this query using the fetch API of a statement:

164
-   ``fetch($fetchStyle)`` - Retrieves the next row from the statement or false if there are none.
165
    Moves the pointer forward one row, so that consecutive calls will always return the next row.
166
-   ``fetchColumn($column)`` - Retrieves only one column of the next row specified by column index.
167
    Moves the pointer forward one row, so that consecutive calls will always return the next row.
168
-   ``fetchAll($fetchStyle)`` - Retrieves all rows from the statement.
169 170 171 172 173 174 175

The fetch API of a prepared statement obviously works only for ``SELECT`` queries.

If you find it tedious to write all the prepared statement code you can alternatively use
the ``Doctrine\DBAL\Connection#executeQuery()`` and ``Doctrine\DBAL\Connection#executeUpdate()``
methods. See the API section below on details how to use them.

176
Additionally there are lots of convenience methods for data-retrieval and manipulation
177 178 179 180
on the Connection, which are all described in the API section below.

Binding Types
-------------
181 182 183 184 185 186 187 188 189 190 191 192 193

Doctrine DBAL extends PDOs handling of binding types in prepared statement
considerably. Besides the well known ``\PDO::PARAM_*`` constants you
can make use of two very powerful additional features.

Doctrine\DBAL\Types Conversion
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

If you don't specify an integer (through a ``PDO::PARAM*`` constant) to
any of the parameter binding methods but a string, Doctrine DBAL will
ask the type abstraction layer to convert the passed value from
its PHP to a database representation. This way you can pass ``\DateTime``
instances to a prepared statement and have Doctrine convert them 
194
to the appropriate vendors database format:
195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249

.. code-block:: php

    <?php
    $date = new \DateTime("2011-03-05 14:00:21");
    $stmt = $conn->prepare("SELECT * FROM articles WHERE publish_date > ?");
    $stmt->bindValue(1, $date, "datetime");
    $stmt->execute();

If you take a look at ``Doctrine\DBAL\Types\DateTimeType`` you will see that
parts of the conversion is delegated to a method on the current database platform,
which means this code works independent of the database you are using.

.. note::

    Be aware this type conversion only works with ``Statement#bindValue()``,
    ``Connection#executeQuery()`` and ``Connection#executeUpdate()``. It
    is not supported to pass a doctrine type name to ``Statement#bindParam()``,
    because this would not work with binding by reference.

List of Parameters Conversion
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

.. note::

    This is a Doctrine 2.1 feature.

One rather annoying bit of missing functionality in SQL is the support for lists of parameters.
You cannot bind an array of values into a single prepared statement parameter. Consider
the following very common SQL statement:

.. code-block:: sql

    SELECT * FROM articles WHERE id IN (?)

Since you are using an ``IN`` expression you would really like to use it in the following way
(and I guess everybody has tried to do this once in his life, before realizing it doesn't work):

.. code-block:: php

    <?php
    $stmt = $conn->prepare('SELECT * FROM articles WHERE id IN (?)');
    // THIS WILL NOT WORK:
    $stmt->bindValue(1, array(1, 2, 3, 4, 5, 6));
    $stmt->execute();

Implementing a generic way to handle this kind of query is tedious work. This is why most
developers fallback to inserting the parameters directly into the query, which can open
SQL injection possibilities if not handled carefully.

Doctrine DBAL implements a very powerful parsing process that will make this kind of prepared
statement possible natively in the binding type system.
The parsing necessarily comes with a performance overhead, but only if you really use a list of parameters.
There are two special binding types that describe a list of integers or strings:

250 251
-   ``\Doctrine\DBAL\Connection::PARAM_INT_ARRAY``
-   ``\Doctrine\DBAL\Connection::PARAM_STR_ARRAY``
252 253 254 255 256 257 258 259

Using one of this constants as a type you can activate the SQLParser inside Doctrine that rewrites
the SQL and flattens the specified values into the set of parameters. Consider our previous example:

.. code-block:: php

    <?php
    $stmt = $conn->executeQuery('SELECT * FROM articles WHERE id IN (?)',
260 261
        array(array(1, 2, 3, 4, 5, 6)),
        array(\Doctrine\DBAL\Connection::PARAM_INT_ARRAY)
262 263
    );

264
The SQL statement passed to ``Connection#executeQuery`` is not the one actually passed to the
265
database. It is internally rewritten to look like the following explicit code that could
266
be specified as well:
267

268 269
.. code-block:: php

270 271 272
    <?php
    // Same SQL WITHOUT usage of Doctrine\DBAL\Connection::PARAM_INT_ARRAY
    $stmt = $conn->executeQuery('SELECT * FROM articles WHERE id IN (?, ?, ?, ?, ?, ?)',
273 274
        array(1, 2, 3, 4, 5, 6),
        array(\PDO::PARAM_INT, \PDO::PARAM_INT, \PDO::PARAM_INT, \PDO::PARAM_INT, \PDO::PARAM_INT, \PDO::PARAM_INT)
275 276 277 278 279 280 281 282 283 284 285 286 287
    );

This is much more complicated and is ugly to write generically.

.. note::

    The parameter list support only works with ``Doctrine\DBAL\Connection::executeQuery()``
    and ``Doctrine\DBAL\Connection::executeUpdate()``, NOT with the binding methods of
    a prepared statement.

API
---

288 289 290 291 292
The DBAL contains several methods for executing queries against
your configured database for data retrieval and manipulation. Below
we'll introduce these methods and provide some examples for each of
them.

Benjamin Eberlei's avatar
Benjamin Eberlei committed
293
prepare()
294
~~~~~~~~~
295

296
Prepare a given SQL statement and return the
297 298
``\Doctrine\DBAL\Driver\Statement`` instance:

299
.. code-block:: php
300 301 302 303 304 305 306 307 308 309

    <?php
    $statement = $conn->prepare('SELECT * FROM user');
    $statement->execute();
    $users = $statement->fetchAll();
    
    /*
    array(
      0 => array(
        'username' => 'jwage',
310
        'password' => 'changeme'
311 312 313 314
      )
    )
    */

Benjamin Eberlei's avatar
Benjamin Eberlei committed
315
executeUpdate()
316
~~~~~~~~~~~~~~~
317

318
Executes a prepared statement with the given SQL and parameters and
319 320
returns the affected rows count:

321
.. code-block:: php
322 323 324 325 326 327 328 329 330 331

    <?php
    $count = $conn->executeUpdate('UPDATE user SET username = ? WHERE id = ?', array('jwage', 1));
    echo $count; // 1

The ``$types`` variable contains the PDO or Doctrine Type constants
to perform necessary type conversions between actual input
parameters and expected database values. See the
`Types <./types#type-conversion>`_ section for more information.

Benjamin Eberlei's avatar
Benjamin Eberlei committed
332
executeQuery()
333
~~~~~~~~~~~~~~
334

335
Creates a prepared statement for the given SQL and passes the
336 337
parameters to the execute method, then returning the statement:

338
.. code-block:: php
339 340

    <?php
341
    $statement = $conn->executeQuery('SELECT * FROM user WHERE username = ?', array('jwage'));
342 343 344 345 346
    $user = $statement->fetch();
    
    /*
    array(
      0 => 'jwage',
347
      1 => 'changeme'
348 349 350 351 352 353 354 355
    )
    */

The ``$types`` variable contains the PDO or Doctrine Type constants
to perform necessary type conversions between actual input
parameters and expected database values. See the
`Types <./types#type-conversion>`_ section for more information.

Benjamin Eberlei's avatar
Benjamin Eberlei committed
356
fetchAll()
357
~~~~~~~~~~
358 359 360

Execute the query and fetch all results into an array:

361
.. code-block:: php
362 363 364 365 366 367 368 369

    <?php
    $users = $conn->fetchAll('SELECT * FROM user');
    
    /*
    array(
      0 => array(
        'username' => 'jwage',
370
        'password' => 'changeme'
371 372 373 374
      )
    )
    */

Benjamin Eberlei's avatar
Benjamin Eberlei committed
375
fetchArray()
376
~~~~~~~~~~~~
377 378 379

Numeric index retrieval of first result row of the given query:

380
.. code-block:: php
381 382 383 384 385 386 387

    <?php
    $user = $conn->fetchArray('SELECT * FROM user WHERE username = ?', array('jwage'));
    
    /*
    array(
      0 => 'jwage',
388
      1 => 'changeme'
389 390 391
    )
    */

Benjamin Eberlei's avatar
Benjamin Eberlei committed
392
fetchColumn()
393
~~~~~~~~~~~~~
394 395 396

Retrieve only the given column of the first result row.

397
.. code-block:: php
398 399 400 401 402

    <?php
    $username = $conn->fetchColumn('SELECT username FROM user WHERE id = ?', array(1), 0);
    echo $username; // jwage

Benjamin Eberlei's avatar
Benjamin Eberlei committed
403
fetchAssoc()
404
~~~~~~~~~~~~
405 406 407

Retrieve assoc row of the first result row.

408
.. code-block:: php
409 410 411 412 413 414

    <?php
    $user = $conn->fetchAssoc('SELECT * FROM user WHERE username = ?', array('jwage'));
    /*
    array(
      'username' => 'jwage',
415
      'password' => 'changeme'
416 417 418 419 420
    )
    */

There are also convenience methods for data manipulation queries:

Benjamin Eberlei's avatar
Benjamin Eberlei committed
421
delete()
422
~~~~~~~~~
423 424 425 426

Delete all rows of a table matching the given identifier, where
keys are column names.

427
.. code-block:: php
428 429 430 431 432

    <?php
    $conn->delete('user', array('id' => 1));
    // DELETE FROM user WHERE id = ? (1)

Benjamin Eberlei's avatar
Benjamin Eberlei committed
433
insert()
434
~~~~~~~~~
435 436 437 438

Insert a row into the given table name using the key value pairs of
data.

439
.. code-block:: php
440 441 442 443 444

    <?php
    $conn->insert('user', array('username' => 'jwage'));
    // INSERT INTO user (username) VALUES (?) (jwage)

Benjamin Eberlei's avatar
Benjamin Eberlei committed
445
update()
446
~~~~~~~~~
447 448 449 450

Update all rows for the matching key value identifiers with the
given data.

451
.. code-block:: php
452 453 454 455 456 457 458 459 460 461 462 463

    <?php
    $conn->update('user', array('username' => 'jwage'), array('id' => 1));
    // UPDATE user (username) VALUES (?) WHERE id = ? (jwage, 1)

By default the Doctrine DBAL does no escaping. Escaping is a very
tricky business to do automatically, therefore there is none by
default. The ORM internally escapes all your values, because it has
lots of metadata available about the current context. When you use
the Doctrine DBAL as standalone, you have to take care of this
yourself. The following methods help you with it:

Benjamin Eberlei's avatar
Benjamin Eberlei committed
464
quote()
465
~~~~~~~~~
466 467 468

Quote a value:

469
.. code-block:: php
470 471 472

    <?php
    $quoted = $conn->quote('value');
Benjamin Eberlei's avatar
Benjamin Eberlei committed
473
    $quoted = $conn->quote('1234', \PDO::PARAM_INT);
474

Benjamin Eberlei's avatar
Benjamin Eberlei committed
475
quoteIdentifier()
476
~~~~~~~~~~~~~~~~~
477 478 479

Quote an identifier according to the platform details.

480
.. code-block:: php
481 482 483 484

    <?php
    $quoted = $conn->quoteIdentifier('id');