sql.txt 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294
  1. ==========================
  2. Performing raw SQL queries
  3. ==========================
  4. .. currentmodule:: django.db.models
  5. When the :doc:`model query APIs </topics/db/queries>` don't go far enough, you
  6. can fall back to writing raw SQL. Django gives you two ways of performing raw
  7. SQL queries: you can use :meth:`Manager.raw()` to `perform raw queries and
  8. return model instances`__, or you can avoid the model layer entirely and
  9. `execute custom SQL directly`__.
  10. __ `performing raw queries`_
  11. __ `executing custom SQL directly`_
  12. .. _executing-raw-queries:
  13. Performing raw queries
  14. ======================
  15. .. versionadded:: 1.2
  16. The ``raw()`` manager method can be used to perform raw SQL queries that
  17. return model instances:
  18. .. method:: Manager.raw(raw_query, params=None, translations=None)
  19. This method method takes a raw SQL query, executes it, and returns a
  20. :class:`~django.db.models.query.RawQuerySet` instance. This
  21. :class:`~django.db.models.query.RawQuerySet` instance can be iterated
  22. over just like an normal QuerySet to provide object instances.
  23. This is best illustrated with an example. Suppose you've got the following model::
  24. class Person(models.Model):
  25. first_name = models.CharField(...)
  26. last_name = models.CharField(...)
  27. birth_date = models.DateField(...)
  28. You could then execute custom SQL like so::
  29. >>> for p in Person.objects.raw('SELECT * FROM myapp_person'):
  30. ... print p
  31. John Smith
  32. Jane Jones
  33. Of course, this example isn't very exciting -- it's exactly the same as
  34. running ``Person.objects.all()``. However, ``raw()`` has a bunch of other
  35. options that make it very powerful.
  36. .. admonition:: Model table names
  37. Where'd the name of the ``Person`` table come from in that example?
  38. By default, Django figures out a database table name by joining the
  39. model's "app label" -- the name you used in ``manage.py startapp`` -- to
  40. the model's class name, with an underscore between them. In the example
  41. we've assumed that the ``Person`` model lives in an app named ``myapp``,
  42. so its table would be ``myapp_person``.
  43. For more details check out the documentation for the
  44. :attr:`~Options.db_table` option, which also lets you manually set the
  45. database table name.
  46. .. warning::
  47. No checking is done on the SQL statement that is passed in to ``.raw()``.
  48. Django expects that the statement will return a set of rows from the
  49. database, but does nothing to enforce that. If the query does not
  50. return rows, a (possibly cryptic) error will result.
  51. Mapping query fields to model fields
  52. ------------------------------------
  53. ``raw()`` automatically maps fields in the query to fields on the model.
  54. The order of fields in your query doesn't matter. In other words, both
  55. of the following queries work identically::
  56. >>> Person.objects.raw('SELECT id, first_name, last_name, birth_date FROM myapp_person')
  57. ...
  58. >>> Person.objects.raw('SELECT last_name, birth_date, first_name, id FROM myapp_person')
  59. ...
  60. Matching is done by name. This means that you can use SQL's ``AS`` clauses to
  61. map fields in the query to model fields. So if you had some other table that
  62. had ``Person`` data in it, you could easily map it into ``Person`` instances::
  63. >>> Person.objects.raw('''SELECT first AS first_name,
  64. ... last AS last_name,
  65. ... bd AS birth_date,
  66. ... pk as id,
  67. ... FROM some_other_table''')
  68. As long as the names match, the model instances will be created correctly.
  69. Alternatively, you can map fields in the query to model fields using the
  70. ``translations`` argument to ``raw()``. This is a dictionary mapping names of
  71. fields in the query to names of fields on the model. For example, the above
  72. query could also be written::
  73. >>> name_map = {'first': 'first_name', 'last': 'last_name', 'bd': 'birth_date', 'pk': 'id'}
  74. >>> Person.objects.raw('SELECT * FROM some_other_table', translations=name_map)
  75. Index lookups
  76. -------------
  77. ``raw()`` supports indexing, so if you need only the first result you can
  78. write::
  79. >>> first_person = Person.objects.raw('SELECT * from myapp_person')[0]
  80. However, the indexing and slicing are not performed at the database level. If
  81. you have a big amount of ``Person`` objects in your database, it is more
  82. efficient to limit the query at the SQL level::
  83. >>> first_person = Person.objects.raw('SELECT * from myapp_person LIMIT 1')[0]
  84. Deferring model fields
  85. ----------------------
  86. Fields may also be left out::
  87. >>> people = Person.objects.raw('SELECT id, first_name FROM myapp_person')
  88. The ``Person`` objects returned by this query will be deferred model instances
  89. (see :meth:`~django.db.models.QuerySet.defer()`). This means that the fields
  90. that are omitted from the query will be loaded on demand. For example::
  91. >>> for p in Person.objects.raw('SELECT id, first_name FROM myapp_person'):
  92. ... print p.first_name, # This will be retrieved by the original query
  93. ... print p.last_name # This will be retrieved on demand
  94. ...
  95. John Smith
  96. Jane Jones
  97. From outward appearances, this looks like the query has retrieved both
  98. the first name and last name. However, this example actually issued 3
  99. queries. Only the first names were retrieved by the raw() query -- the
  100. last names were both retrieved on demand when they were printed.
  101. There is only one field that you can't leave out - the primary key
  102. field. Django uses the primary key to identify model instances, so it
  103. must always be included in a raw query. An ``InvalidQuery`` exception
  104. will be raised if you forget to include the primary key.
  105. Adding annotations
  106. ------------------
  107. You can also execute queries containing fields that aren't defined on the
  108. model. For example, we could use `PostgreSQL's age() function`__ to get a list
  109. of people with their ages calculated by the database::
  110. >>> people = Person.objects.raw('SELECT *, age(birth_date) AS age FROM myapp_person')
  111. >>> for p in people:
  112. ... print "%s is %s." % (p.first_name, p.age)
  113. John is 37.
  114. Jane is 42.
  115. ...
  116. __ http://www.postgresql.org/docs/8.4/static/functions-datetime.html
  117. Passing parameters into ``raw()``
  118. ---------------------------------
  119. If you need to perform parameterized queries, you can use the ``params``
  120. argument to ``raw()``::
  121. >>> lname = 'Doe'
  122. >>> Person.objects.raw('SELECT * FROM myapp_person WHERE last_name = %s', [lname])
  123. ``params`` is a list of parameters. You'll use ``%s`` placeholders in the
  124. query string (regardless of your database engine); they'll be replaced with
  125. parameters from the ``params`` list.
  126. .. warning::
  127. **Do not use string formatting on raw queries!**
  128. It's tempting to write the above query as::
  129. >>> query = 'SELECT * FROM myapp_person WHERE last_name = %s' % lname
  130. >>> Person.objects.raw(query)
  131. **Don't.**
  132. Using the ``params`` list completely protects you from `SQL injection
  133. attacks`__, a common exploit where attackers inject arbitrary SQL into
  134. your database. If you use string interpolation, sooner or later you'll
  135. fall victim to SQL injection. As long as you remember to always use the
  136. ``params`` list you'll be protected.
  137. __ http://en.wikipedia.org/wiki/SQL_injection
  138. .. _executing-custom-sql:
  139. Executing custom SQL directly
  140. =============================
  141. Sometimes even :meth:`Manager.raw` isn't quite enough: you might need to
  142. perform queries that don't map cleanly to models, or directly execute
  143. ``UPDATE``, ``INSERT``, or ``DELETE`` queries.
  144. In these cases, you can always access the database directly, routing around
  145. the model layer entirely.
  146. The object ``django.db.connection`` represents the
  147. default database connection, and ``django.db.transaction`` represents the
  148. default database transaction. To use the database connection, call
  149. ``connection.cursor()`` to get a cursor object. Then, call
  150. ``cursor.execute(sql, [params])`` to execute the SQL and ``cursor.fetchone()``
  151. or ``cursor.fetchall()`` to return the resulting rows. After performing a data
  152. changing operation, you should then call
  153. ``transaction.commit_unless_managed()`` to ensure your changes are committed
  154. to the database. If your query is purely a data retrieval operation, no commit
  155. is required. For example::
  156. def my_custom_sql():
  157. from django.db import connection, transaction
  158. cursor = connection.cursor()
  159. # Data modifying operation - commit required
  160. cursor.execute("UPDATE bar SET foo = 1 WHERE baz = %s", [self.baz])
  161. transaction.commit_unless_managed()
  162. # Data retrieval operation - no commit required
  163. cursor.execute("SELECT foo FROM bar WHERE baz = %s", [self.baz])
  164. row = cursor.fetchone()
  165. return row
  166. If you are using more than one database you can use
  167. ``django.db.connections`` to obtain the connection (and cursor) for a
  168. specific database. ``django.db.connections`` is a dictionary-like
  169. object that allows you to retrieve a specific connection using its
  170. alias::
  171. from django.db import connections
  172. cursor = connections['my_db_alias'].cursor()
  173. # Your code here...
  174. transaction.commit_unless_managed(using='my_db_alias')
  175. By default, the Python DB API will return results without their field
  176. names, which means you end up with a ``list`` of values, rather than a
  177. ``dict``. At a small performance cost, you can return results as a
  178. ``dict`` by using something like this::
  179. def dictfetchall(cursor):
  180. "Returns all rows from a cursor as a dict"
  181. desc = cursor.description
  182. return [
  183. dict(zip([col[0] for col in desc], row))
  184. for row in cursor.fetchall()
  185. ]
  186. Here is an example of the difference between the two::
  187. >>> cursor.execute("SELECT id, parent_id from test LIMIT 2");
  188. >>> cursor.fetchall()
  189. ((54360982L, None), (54360880L, None))
  190. >>> cursor.execute("SELECT id, parent_id from test LIMIT 2");
  191. >>> dictfetchall(cursor)
  192. [{'parent_id': None, 'id': 54360982L}, {'parent_id': None, 'id': 54360880L}]
  193. .. _transactions-and-raw-sql:
  194. Transactions and raw SQL
  195. ------------------------
  196. When you make a raw SQL call, Django will automatically mark the
  197. current transaction as dirty. You must then ensure that the
  198. transaction containing those calls is closed correctly. See :ref:`the
  199. notes on the requirements of Django's transaction handling
  200. <topics-db-transactions-requirements>` for more details.
  201. .. versionchanged:: 1.3
  202. Prior to Django 1.3, it was necessary to manually mark a transaction
  203. as dirty using ``transaction.set_dirty()`` when using raw SQL calls.
  204. Connections and cursors
  205. -----------------------
  206. ``connection`` and ``cursor`` mostly implement the standard Python DB-API
  207. described in :pep:`249` (except when it comes to :doc:`transaction handling
  208. </topics/db/transactions>`). If you're not familiar with the Python DB-API, note
  209. that the SQL statement in ``cursor.execute()`` uses placeholders, ``"%s"``,
  210. rather than adding parameters directly within the SQL. If you use this
  211. technique, the underlying database library will automatically add quotes and
  212. escaping to your parameter(s) as necessary. (Also note that Django expects the
  213. ``"%s"`` placeholder, *not* the ``"?"`` placeholder, which is used by the SQLite
  214. Python bindings. This is for the sake of consistency and sanity.)