sql.txt 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396
  1. ==========================
  2. Performing raw SQL queries
  3. ==========================
  4. .. currentmodule:: django.db.models
  5. Django gives you two ways of performing raw SQL queries: you can use
  6. :meth:`Manager.raw()` to `perform raw queries and return model instances`__, or
  7. you can avoid the model layer entirely and `execute custom SQL directly`__.
  8. __ `performing raw queries`_
  9. __ `executing custom SQL directly`_
  10. .. admonition:: Explore the ORM before using raw SQL!
  11. The Django ORM provides many tools to express queries without writing raw
  12. SQL. For example:
  13. * The :doc:`QuerySet API </ref/models/querysets>` is extensive.
  14. * You can :meth:`annotate <.QuerySet.annotate>` and :doc:`aggregate
  15. </topics/db/aggregation>` using many built-in :doc:`database functions
  16. </ref/models/database-functions>`. Beyond those, you can create
  17. :doc:`custom query expressions </ref/models/expressions/>`.
  18. Before using raw SQL, explore :doc:`the ORM </topics/db/index>`. Ask on
  19. |django-users| or the `#django IRC channel
  20. <https://webchat.freenode.net/#django>`_ to see if the ORM supports your
  21. use case.
  22. .. warning::
  23. You should be very careful whenever you write raw SQL. Every time you use
  24. it, you should properly escape any parameters that the user can control
  25. by using ``params`` in order to protect against SQL injection attacks.
  26. Please read more about :ref:`SQL injection protection
  27. <sql-injection-protection>`.
  28. .. _executing-raw-queries:
  29. Performing raw queries
  30. ======================
  31. The ``raw()`` manager method can be used to perform raw SQL queries that
  32. return model instances:
  33. .. method:: Manager.raw(raw_query, params=(), translations=None)
  34. This method takes a raw SQL query, executes it, and returns a
  35. ``django.db.models.query.RawQuerySet`` instance. This ``RawQuerySet`` instance
  36. can be iterated over like a normal :class:`~django.db.models.query.QuerySet` to
  37. provide object instances.
  38. This is best illustrated with an example. Suppose you have the following model::
  39. class Person(models.Model):
  40. first_name = models.CharField(...)
  41. last_name = models.CharField(...)
  42. birth_date = models.DateField(...)
  43. You could then execute custom SQL like so::
  44. >>> for p in Person.objects.raw('SELECT * FROM myapp_person'):
  45. ... print(p)
  46. John Smith
  47. Jane Jones
  48. This example isn't very exciting -- it's exactly the same as running
  49. ``Person.objects.all()``. However, ``raw()`` has a bunch of other options that
  50. make it very powerful.
  51. .. admonition:: Model table names
  52. Where did the name of the ``Person`` table come from in that example?
  53. By default, Django figures out a database table name by joining the
  54. model's "app label" -- the name you used in ``manage.py startapp`` -- to
  55. the model's class name, with an underscore between them. In the example
  56. we've assumed that the ``Person`` model lives in an app named ``myapp``,
  57. so its table would be ``myapp_person``.
  58. For more details check out the documentation for the
  59. :attr:`~Options.db_table` option, which also lets you manually set the
  60. database table name.
  61. .. warning::
  62. No checking is done on the SQL statement that is passed in to ``.raw()``.
  63. Django expects that the statement will return a set of rows from the
  64. database, but does nothing to enforce that. If the query does not
  65. return rows, a (possibly cryptic) error will result.
  66. .. warning::
  67. If you are performing queries on MySQL, note that MySQL's silent type coercion
  68. may cause unexpected results when mixing types. If you query on a string
  69. type column, but with an integer value, MySQL will coerce the types of all values
  70. in the table to an integer before performing the comparison. For example, if your
  71. table contains the values ``'abc'``, ``'def'`` and you query for ``WHERE mycolumn=0``,
  72. both rows will match. To prevent this, perform the correct typecasting
  73. before using the value in a query.
  74. .. versionchanged:: 3.2
  75. The default value of the ``params`` argument was changed from ``None`` to
  76. an empty tuple.
  77. Mapping query fields to model fields
  78. ------------------------------------
  79. ``raw()`` automatically maps fields in the query to fields on the model.
  80. The order of fields in your query doesn't matter. In other words, both
  81. of the following queries work identically::
  82. >>> Person.objects.raw('SELECT id, first_name, last_name, birth_date FROM myapp_person')
  83. ...
  84. >>> Person.objects.raw('SELECT last_name, birth_date, first_name, id FROM myapp_person')
  85. ...
  86. Matching is done by name. This means that you can use SQL's ``AS`` clauses to
  87. map fields in the query to model fields. So if you had some other table that
  88. had ``Person`` data in it, you could easily map it into ``Person`` instances::
  89. >>> Person.objects.raw('''SELECT first AS first_name,
  90. ... last AS last_name,
  91. ... bd AS birth_date,
  92. ... pk AS id,
  93. ... FROM some_other_table''')
  94. As long as the names match, the model instances will be created correctly.
  95. Alternatively, you can map fields in the query to model fields using the
  96. ``translations`` argument to ``raw()``. This is a dictionary mapping names of
  97. fields in the query to names of fields on the model. For example, the above
  98. query could also be written::
  99. >>> name_map = {'first': 'first_name', 'last': 'last_name', 'bd': 'birth_date', 'pk': 'id'}
  100. >>> Person.objects.raw('SELECT * FROM some_other_table', translations=name_map)
  101. Index lookups
  102. -------------
  103. ``raw()`` supports indexing, so if you need only the first result you can
  104. write::
  105. >>> first_person = Person.objects.raw('SELECT * FROM myapp_person')[0]
  106. However, the indexing and slicing are not performed at the database level. If
  107. you have a large number of ``Person`` objects in your database, it is more
  108. efficient to limit the query at the SQL level::
  109. >>> first_person = Person.objects.raw('SELECT * FROM myapp_person LIMIT 1')[0]
  110. Deferring model fields
  111. ----------------------
  112. Fields may also be left out::
  113. >>> people = Person.objects.raw('SELECT id, first_name FROM myapp_person')
  114. The ``Person`` objects returned by this query will be deferred model instances
  115. (see :meth:`~django.db.models.query.QuerySet.defer()`). This means that the
  116. fields that are omitted from the query will be loaded on demand. For example::
  117. >>> for p in Person.objects.raw('SELECT id, first_name FROM myapp_person'):
  118. ... print(p.first_name, # This will be retrieved by the original query
  119. ... p.last_name) # This will be retrieved on demand
  120. ...
  121. John Smith
  122. Jane Jones
  123. From outward appearances, this looks like the query has retrieved both
  124. the first name and last name. However, this example actually issued 3
  125. queries. Only the first names were retrieved by the raw() query -- the
  126. last names were both retrieved on demand when they were printed.
  127. There is only one field that you can't leave out - the primary key
  128. field. Django uses the primary key to identify model instances, so it
  129. must always be included in a raw query. A
  130. :class:`~django.core.exceptions.FieldDoesNotExist` exception will be raised if
  131. you forget to include the primary key.
  132. Adding annotations
  133. ------------------
  134. You can also execute queries containing fields that aren't defined on the
  135. model. For example, we could use `PostgreSQL's age() function`__ to get a list
  136. of people with their ages calculated by the database::
  137. >>> people = Person.objects.raw('SELECT *, age(birth_date) AS age FROM myapp_person')
  138. >>> for p in people:
  139. ... print("%s is %s." % (p.first_name, p.age))
  140. John is 37.
  141. Jane is 42.
  142. ...
  143. You can often avoid using raw SQL to compute annotations by instead using a
  144. :ref:`Func() expression <func-expressions>`.
  145. __ https://www.postgresql.org/docs/current/functions-datetime.html
  146. Passing parameters into ``raw()``
  147. ---------------------------------
  148. If you need to perform parameterized queries, you can use the ``params``
  149. argument to ``raw()``::
  150. >>> lname = 'Doe'
  151. >>> Person.objects.raw('SELECT * FROM myapp_person WHERE last_name = %s', [lname])
  152. ``params`` is a list or dictionary of parameters. You'll use ``%s``
  153. placeholders in the query string for a list, or ``%(key)s``
  154. placeholders for a dictionary (where ``key`` is replaced by a
  155. dictionary key), regardless of your database engine. Such placeholders will be
  156. replaced with parameters from the ``params`` argument.
  157. .. note::
  158. Dictionary params are not supported with the SQLite backend; with
  159. this backend, you must pass parameters as a list.
  160. .. warning::
  161. **Do not use string formatting on raw queries or quote placeholders in your
  162. SQL strings!**
  163. It's tempting to write the above query as::
  164. >>> query = 'SELECT * FROM myapp_person WHERE last_name = %s' % lname
  165. >>> Person.objects.raw(query)
  166. You might also think you should write your query like this (with quotes
  167. around ``%s``)::
  168. >>> query = "SELECT * FROM myapp_person WHERE last_name = '%s'"
  169. **Don't make either of these mistakes.**
  170. As discussed in :ref:`sql-injection-protection`, using the ``params``
  171. argument and leaving the placeholders unquoted protects you from `SQL
  172. injection attacks`__, a common exploit where attackers inject arbitrary
  173. SQL into your database. If you use string interpolation or quote the
  174. placeholder, you're at risk for SQL injection.
  175. __ https://en.wikipedia.org/wiki/SQL_injection
  176. .. _executing-custom-sql:
  177. Executing custom SQL directly
  178. =============================
  179. Sometimes even :meth:`Manager.raw` isn't quite enough: you might need to
  180. perform queries that don't map cleanly to models, or directly execute
  181. ``UPDATE``, ``INSERT``, or ``DELETE`` queries.
  182. In these cases, you can always access the database directly, routing around
  183. the model layer entirely.
  184. The object ``django.db.connection`` represents the default database
  185. connection. To use the database connection, call ``connection.cursor()`` to
  186. get a cursor object. Then, call ``cursor.execute(sql, [params])`` to execute
  187. the SQL and ``cursor.fetchone()`` or ``cursor.fetchall()`` to return the
  188. resulting rows.
  189. For example::
  190. from django.db import connection
  191. def my_custom_sql(self):
  192. with connection.cursor() as cursor:
  193. cursor.execute("UPDATE bar SET foo = 1 WHERE baz = %s", [self.baz])
  194. cursor.execute("SELECT foo FROM bar WHERE baz = %s", [self.baz])
  195. row = cursor.fetchone()
  196. return row
  197. To protect against SQL injection, you must not include quotes around the ``%s``
  198. placeholders in the SQL string.
  199. Note that if you want to include literal percent signs in the query, you have to
  200. double them in the case you are passing parameters::
  201. cursor.execute("SELECT foo FROM bar WHERE baz = '30%'")
  202. cursor.execute("SELECT foo FROM bar WHERE baz = '30%%' AND id = %s", [self.id])
  203. If you are using :doc:`more than one database </topics/db/multi-db>`, you can
  204. use ``django.db.connections`` to obtain the connection (and cursor) for a
  205. specific database. ``django.db.connections`` is a dictionary-like
  206. object that allows you to retrieve a specific connection using its
  207. alias::
  208. from django.db import connections
  209. with connections['my_db_alias'].cursor() as cursor:
  210. # Your code here...
  211. By default, the Python DB API will return results without their field names,
  212. which means you end up with a ``list`` of values, rather than a ``dict``. At a
  213. small performance and memory cost, you can return results as a ``dict`` by
  214. using something like this::
  215. def dictfetchall(cursor):
  216. "Return all rows from a cursor as a dict"
  217. columns = [col[0] for col in cursor.description]
  218. return [
  219. dict(zip(columns, row))
  220. for row in cursor.fetchall()
  221. ]
  222. Another option is to use :func:`collections.namedtuple` from the Python
  223. standard library. A ``namedtuple`` is a tuple-like object that has fields
  224. accessible by attribute lookup; it's also indexable and iterable. Results are
  225. immutable and accessible by field names or indices, which might be useful::
  226. from collections import namedtuple
  227. def namedtuplefetchall(cursor):
  228. "Return all rows from a cursor as a namedtuple"
  229. desc = cursor.description
  230. nt_result = namedtuple('Result', [col[0] for col in desc])
  231. return [nt_result(*row) for row in cursor.fetchall()]
  232. Here is an example of the difference between the three::
  233. >>> cursor.execute("SELECT id, parent_id FROM test LIMIT 2");
  234. >>> cursor.fetchall()
  235. ((54360982, None), (54360880, None))
  236. >>> cursor.execute("SELECT id, parent_id FROM test LIMIT 2");
  237. >>> dictfetchall(cursor)
  238. [{'parent_id': None, 'id': 54360982}, {'parent_id': None, 'id': 54360880}]
  239. >>> cursor.execute("SELECT id, parent_id FROM test LIMIT 2");
  240. >>> results = namedtuplefetchall(cursor)
  241. >>> results
  242. [Result(id=54360982, parent_id=None), Result(id=54360880, parent_id=None)]
  243. >>> results[0].id
  244. 54360982
  245. >>> results[0][0]
  246. 54360982
  247. Connections and cursors
  248. -----------------------
  249. ``connection`` and ``cursor`` mostly implement the standard Python DB-API
  250. described in :pep:`249` — except when it comes to :doc:`transaction handling
  251. </topics/db/transactions>`.
  252. If you're not familiar with the Python DB-API, note that the SQL statement in
  253. ``cursor.execute()`` uses placeholders, ``"%s"``, rather than adding
  254. parameters directly within the SQL. If you use this technique, the underlying
  255. database library will automatically escape your parameters as necessary.
  256. Also note that Django expects the ``"%s"`` placeholder, *not* the ``"?"``
  257. placeholder, which is used by the SQLite Python bindings. This is for the sake
  258. of consistency and sanity.
  259. Using a cursor as a context manager::
  260. with connection.cursor() as c:
  261. c.execute(...)
  262. is equivalent to::
  263. c = connection.cursor()
  264. try:
  265. c.execute(...)
  266. finally:
  267. c.close()
  268. Calling stored procedures
  269. ~~~~~~~~~~~~~~~~~~~~~~~~~
  270. .. method:: CursorWrapper.callproc(procname, params=None, kparams=None)
  271. Calls a database stored procedure with the given name. A sequence
  272. (``params``) or dictionary (``kparams``) of input parameters may be
  273. provided. Most databases don't support ``kparams``. Of Django's built-in
  274. backends, only Oracle supports it.
  275. For example, given this stored procedure in an Oracle database:
  276. .. code-block:: sql
  277. CREATE PROCEDURE "TEST_PROCEDURE"(v_i INTEGER, v_text NVARCHAR2(10)) AS
  278. p_i INTEGER;
  279. p_text NVARCHAR2(10);
  280. BEGIN
  281. p_i := v_i;
  282. p_text := v_text;
  283. ...
  284. END;
  285. This will call it::
  286. with connection.cursor() as cursor:
  287. cursor.callproc('test_procedure', [1, 'test'])