sql.txt 14 KB

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