File: sqlexpressions.rst

package info (click to toggle)
sqlalchemy 1.4.46%2Bds1-1
  • links: PTS, VCS
  • area: main
  • in suites: bookworm
  • size: 22,444 kB
  • sloc: python: 341,434; ansic: 1,760; makefile: 226; xml: 17; sh: 7
file content (511 lines) | stat: -rw-r--r-- 20,611 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
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
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
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
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
SQL Expressions
===============

.. contents::
    :local:
    :class: faq
    :backlinks: none

.. _faq_sql_expression_string:

How do I render SQL expressions as strings, possibly with bound parameters inlined?
------------------------------------------------------------------------------------

The "stringification" of a SQLAlchemy Core statement object or
expression fragment, as well as that of an ORM :class:`_query.Query` object,
in the majority of simple cases is as simple as using
the ``str()`` builtin function, as below when use it with the ``print``
function (note the Python ``print`` function also calls ``str()`` automatically
if we don't use it explicitly)::

    >>> from sqlalchemy import table, column, select
    >>> t = table("my_table", column("x"))
    >>> statement = select(t)
    >>> print(str(statement))
    SELECT my_table.x
    FROM my_table

The ``str()`` builtin, or an equivalent, can be invoked on ORM
:class:`_query.Query`  object as well as any statement such as that of
:func:`_expression.select`, :func:`_expression.insert` etc. and also any expression fragment, such
as::

    >>> from sqlalchemy import column
    >>> print(column("x") == "some value")
    x = :x_1

Stringifying for Specific Databases
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

A complication arises when the statement or fragment we are stringifying
contains elements that have a database-specific string format, or when it
contains elements that are only available within a certain kind of database.
In these cases, we might get a stringified statement that is not in the correct
syntax for the database we are targeting, or the operation may raise a
:class:`.UnsupportedCompilationError` exception.   In these cases, it is
necessary that we stringify the statement using the
:meth:`_expression.ClauseElement.compile` method, while passing along an :class:`_engine.Engine`
or :class:`.Dialect` object that represents the target database.  Such as
below, if we have a MySQL database engine, we can stringify a statement in
terms of the MySQL dialect::

    from sqlalchemy import create_engine

    engine = create_engine("mysql+pymysql://scott:tiger@localhost/test")
    print(statement.compile(engine))

More directly, without building up an :class:`_engine.Engine` object we can
instantiate a :class:`.Dialect` object directly, as below where we
use a PostgreSQL dialect::

    from sqlalchemy.dialects import postgresql

    print(statement.compile(dialect=postgresql.dialect()))

Note that any dialect can be assembled using :func:`_sa.create_engine` itself
with a dummy URL and then accessing the :attr:`_engine.Engine.dialect` attribute,
such as if we wanted a dialect object for psycopg2::

    e = create_engine("postgresql+psycopg2://")
    psycopg2_dialect = e.dialect

When given an ORM :class:`~.orm.query.Query` object, in order to get at the
:meth:`_expression.ClauseElement.compile`
method we only need access the :attr:`~.orm.query.Query.statement`
accessor first::

    statement = query.statement
    print(statement.compile(someengine))

Rendering Bound Parameters Inline
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

.. warning:: **Never** use these techniques with string content received from
   untrusted input, such as from web forms or other user-input applications.
   SQLAlchemy's facilities to  coerce Python values into direct SQL string
   values are **not secure against untrusted input and do not validate the type
   of data being passed**. Always use bound parameters when programmatically
   invoking non-DDL SQL statements against a relational database.

The above forms will render the SQL statement as it is passed to the Python
:term:`DBAPI`, which includes that bound parameters are not rendered inline.
SQLAlchemy normally does not stringify bound parameters, as this is handled
appropriately by the Python DBAPI, not to mention bypassing bound
parameters is probably the most widely exploited security hole in
modern web applications.   SQLAlchemy has limited ability to do this
stringification in certain circumstances such as that of emitting DDL.
In order to access this functionality one can use the ``literal_binds``
flag, passed to ``compile_kwargs``::

    from sqlalchemy.sql import table, column, select

    t = table("t", column("x"))

    s = select(t).where(t.c.x == 5)

    # **do not use** with untrusted input!!!
    print(s.compile(compile_kwargs={"literal_binds": True}))

    # to render for a specific dialect
    print(s.compile(dialect=dialect, compile_kwargs={"literal_binds": True}))

    # or if you have an Engine, pass as first argument
    print(s.compile(some_engine, compile_kwargs={"literal_binds": True}))

This functionality is provided mainly for logging or debugging purposes, where
having the raw sql string of a query may prove useful.

The above approach has the caveats that it is only supported for basic types,
such as ints and strings, and furthermore if a :func:`.bindparam` without a
pre-set value is used directly, it won't be able to stringify that either.
Methods of stringifying all parameters unconditionally are detailed below.

.. tip::

   The reason SQLAlchemy does not support full stringification of all
   datatypes is threefold:

   1. This is a functionality that is already supported by the DBAPI in use
      when the DBAPI is used normally.   The SQLAlchemy project cannot be
      tasked with duplicating this functionality for every datatype for
      all backends, as this is redundant work which also incurs significant
      testing and ongoing support overhead.

   2. Stringifying with bound parameters inlined for specific databases
      suggests a usage that is actually passing these fully stringified
      statements onto the database for execution. This is unnecessary and
      insecure, and SQLAlchemy does not want to encourage this use in any
      way.

   3. The area of rendering literal values is the most likely area for
      security issues to be reported.  SQLAlchemy tries to keep the area of
      safe parameter stringification an issue for the DBAPI drivers as much
      as possible where the specifics for each DBAPI can be handled
      appropriately and securely.

As SQLAlchemy intentionally does not support full stringification of literal
values, techniques to do so within specific debugging scenarios include the
following. As an example, we will use the PostgreSQL :class:`_postgresql.UUID`
datatype::

    import uuid

    from sqlalchemy import Column
    from sqlalchemy import create_engine
    from sqlalchemy import Integer
    from sqlalchemy import select
    from sqlalchemy.dialects.postgresql import UUID
    from sqlalchemy.orm import declarative_base


    Base = declarative_base()


    class A(Base):
        __tablename__ = "a"

        id = Column(Integer, primary_key=True)
        data = Column(UUID)


    stmt = select(A).where(A.data == uuid.uuid4())

Given the above model and statement which will compare a column to a single
UUID value, options for stringifying this statement with inline values
include:

* Some DBAPIs such as psycopg2 support helper functions like
  `mogrify() <https://www.psycopg.org/docs/cursor.html#cursor.mogrify>`_ which
  provide access to their literal-rendering functionality.   To use such
  features, render the SQL string without using ``literal_binds`` and pass
  the parameters separately via the :attr:`.SQLCompiler.params` accessor::

      e = create_engine("postgresql+psycopg2://scott:tiger@localhost/test")

      with e.connect() as conn:
          cursor = conn.connection.cursor()
          compiled = stmt.compile(e)

          print(cursor.mogrify(str(compiled), compiled.params))

  The above code will produce psycopg2's raw bytestring::

      b"SELECT a.id, a.data \nFROM a \nWHERE a.data = 'a511b0fc-76da-4c47-a4b4-716a8189b7ac'::uuid"

* Render the :attr:`.SQLCompiler.params` directly into the statement, using
  the appropriate `paramstyle <https://www.python.org/dev/peps/pep-0249/#paramstyle>`_
  of the target DBAPI.  For example, the psycopg2 DBAPI uses the named ``pyformat``
  style.  The meaning of ``render_postcompile`` will be discussed in the next
  section.   **WARNING this is NOT secure, do NOT use untrusted input**::

    e = create_engine("postgresql+psycopg2://")

    # will use pyformat style, i.e. %(paramname)s for param
    compiled = stmt.compile(e, compile_kwargs={"render_postcompile": True})

    print(str(compiled) % compiled.params)

  This will produce a non-working string, that nonetheless is suitable for
  debugging::

    SELECT a.id, a.data
    FROM a
    WHERE a.data = 9eec1209-50b4-4253-b74b-f82461ed80c1

  Another example using a positional paramstyle such as ``qmark``, we can render
  our above statement in terms of SQLite by also using the
  :attr:`.SQLCompiler.positiontup` collection in conjunction with
  :attr:`.SQLCompiler.params`, in order to retrieve the parameters in
  their positional order for the statement as compiled::

    import re

    e = create_engine("sqlite+pysqlite://")

    # will use qmark style, i.e. ? for param
    compiled = stmt.compile(e, compile_kwargs={"render_postcompile": True})

    # params in positional order
    params = (repr(compiled.params[name]) for name in compiled.positiontup)

    print(re.sub(r"\?", lambda m: next(params), str(compiled)))

  The above snippet prints::

    SELECT a.id, a.data
    FROM a
    WHERE a.data = UUID('1bd70375-db17-4d8c-94f1-fc2ef3aada26')

* Use the :ref:`sqlalchemy.ext.compiler_toplevel` extension to render
  :class:`_sql.BindParameter` objects in a custom way when a user-defined
  flag is present.  This flag is sent through the ``compile_kwargs``
  dictionary like any other flag::

    from sqlalchemy.ext.compiler import compiles
    from sqlalchemy.sql.expression import BindParameter


    @compiles(BindParameter)
    def _render_literal_bindparam(element, compiler, use_my_literal_recipe=False, **kw):
        if not use_my_literal_recipe:
            # use normal bindparam processing
            return compiler.visit_bindparam(element, **kw)

        # if use_my_literal_recipe was passed to compiler_kwargs,
        # render the value directly
        return repr(element.value)


    e = create_engine("postgresql+psycopg2://")
    print(stmt.compile(e, compile_kwargs={"use_my_literal_recipe": True}))

  The above recipe will print::

    SELECT a.id, a.data
    FROM a
    WHERE a.data = UUID('47b154cd-36b2-42ae-9718-888629ab9857')

* For type-specific stringification that's built into a model or a statement, the
  :class:`_types.TypeDecorator` class may be used to provide custom stringification
  of any datatype using the :meth:`.TypeDecorator.process_literal_param` method::

    from sqlalchemy import TypeDecorator


    class UUIDStringify(TypeDecorator):
        impl = UUID

        def process_literal_param(self, value, dialect):
            return repr(value)

  The above datatype needs to be used either explicitly within the model
  or locally within the statement using :func:`_sql.type_coerce`, such as ::

    from sqlalchemy import type_coerce

    stmt = select(A).where(type_coerce(A.data, UUIDStringify) == uuid.uuid4())

    print(stmt.compile(e, compile_kwargs={"literal_binds": True}))

  Again printing the same form::

    SELECT a.id, a.data
    FROM a
    WHERE a.data = UUID('47b154cd-36b2-42ae-9718-888629ab9857')

Rendering "POSTCOMPILE" Parameters as Bound Parameters
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

SQLAlchemy includes a variant on a bound parameter known as
:paramref:`_sql.BindParameter.expanding`, which is a "late evaluated" parameter
that is rendered in an intermediary state when a SQL construct is compiled,
which is then further processed at statement execution time when the actual
known values are passed.   "Expanding" parameters are used for
:meth:`_sql.ColumnOperators.in_` expressions by default so that the SQL
string can be safely cached independently of the actual lists of values
being passed to a particular invocation of :meth:`_sql.ColumnOperators.in_`::

  >>> stmt = select(A).where(A.id.in_[1, 2, 3])

To render the IN clause with real bound parameter symbols, use the
``render_postcompile=True`` flag with :meth:`_sql.ClauseElement.compile`::

  >>> e = create_engine("postgresql+psycopg2://")
  >>> print(stmt.compile(e, compile_kwargs={"render_postcompile": True}))
  SELECT a.id, a.data
  FROM a
  WHERE a.id IN (%(id_1_1)s, %(id_1_2)s, %(id_1_3)s)

The ``literal_binds`` flag, described in the previous section regarding
rendering of bound parameters, automatically sets ``render_postcompile`` to
True, so for a statement with simple ints/strings, these can be stringified
directly::

  # render_postcompile is implied by literal_binds
  >>> print(stmt.compile(e, compile_kwargs={"literal_binds": True}))
  SELECT a.id, a.data
  FROM a
  WHERE a.id IN (1, 2, 3)

The :attr:`.SQLCompiler.params` and :attr:`.SQLCompiler.positiontup` are
also compatible with ``render_postcompile``, so that
the previous recipes for rendering inline bound parameters will work here
in the same way, such as SQLite's positional form::

  >>> u1, u2, u3 = uuid.uuid4(), uuid.uuid4(), uuid.uuid4()
  >>> stmt = select(A).where(A.data.in_([u1, u2, u3]))

  >>> import re
  >>> e = create_engine("sqlite+pysqlite://")
  >>> compiled = stmt.compile(e, compile_kwargs={"render_postcompile": True})
  >>> params = (repr(compiled.params[name]) for name in compiled.positiontup)
  >>> print(re.sub(r"\?", lambda m: next(params), str(compiled)))
  SELECT a.id, a.data
  FROM a
  WHERE a.data IN (UUID('aa1944d6-9a5a-45d5-b8da-0ba1ef0a4f38'), UUID('a81920e6-15e2-4392-8a3c-d775ffa9ccd2'), UUID('b5574cdb-ff9b-49a3-be52-dbc89f087bfa'))

.. warning::

    Remember, **all** of the above code recipes which stringify literal
    values, bypassing the use of bound parameters when sending statements
    to the database, are **only to be used when**:

    1. the use is **debugging purposes only**

    2. the string **is not to be passed to a live production database**

    3. only with **local, trusted input**

    The above recipes for stringification of literal values are **not secure in
    any way and should never be used against production databases**.

.. _faq_sql_expression_percent_signs:

Why are percent signs being doubled up when stringifying SQL statements?
------------------------------------------------------------------------

Many :term:`DBAPI` implementations make use of the ``pyformat`` or ``format``
`paramstyle <https://www.python.org/dev/peps/pep-0249/#paramstyle>`_, which
necessarily involve percent signs in their syntax.  Most DBAPIs that do this
expect percent signs used for other reasons to be doubled up (i.e. escaped) in
the string form of the statements used, e.g.::

    SELECT a, b FROM some_table WHERE a = %s AND c = %s AND num %% modulus = 0

When SQL statements are passed to the underlying DBAPI by SQLAlchemy,
substitution of bound parameters works in the same way as the Python string
interpolation operator ``%``, and in many cases the DBAPI actually uses this
operator directly.  Above, the substitution of bound parameters would then look
like::

    SELECT a, b FROM some_table WHERE a = 5 AND c = 10 AND num % modulus = 0

The default compilers for databases like PostgreSQL (default DBAPI is psycopg2)
and MySQL (default DBAPI is mysqlclient) will have this percent sign
escaping behavior::

    >>> from sqlalchemy import table, column
    >>> from sqlalchemy.dialects import postgresql
    >>> t = table("my_table", column("value % one"), column("value % two"))
    >>> print(t.select().compile(dialect=postgresql.dialect()))
    SELECT my_table."value %% one", my_table."value %% two"
    FROM my_table

When such a dialect is being used, if non-DBAPI statements are desired that
don't include bound parameter symbols, one quick way to remove the percent
signs is to simply substitute in an empty set of parameters using Python's
``%`` operator directly::

    >>> strstmt = str(t.select().compile(dialect=postgresql.dialect()))
    >>> print(strstmt % ())
    SELECT my_table."value % one", my_table."value % two"
    FROM my_table

The other is to set a different parameter style on the dialect being used; all
:class:`.Dialect` implementations accept a parameter
``paramstyle`` which will cause the compiler for that
dialect to use the given parameter style.  Below, the very common ``named``
parameter style is set within the dialect used for the compilation so that
percent signs are no longer significant in the compiled form of SQL, and will
no longer be escaped::

    >>> print(t.select().compile(dialect=postgresql.dialect(paramstyle="named")))
    SELECT my_table."value % one", my_table."value % two"
    FROM my_table


.. _faq_sql_expression_op_parenthesis:

I'm using op() to generate a custom operator and my parenthesis are not coming out correctly
---------------------------------------------------------------------------------------------

The :meth:`.Operators.op` method allows one to create a custom database operator
otherwise not known by SQLAlchemy::

    >>> print(column("q").op("->")(column("p")))
    q -> p

However, when using it on the right side of a compound expression, it doesn't
generate parenthesis as we expect::

    >>> print((column("q1") + column("q2")).op("->")(column("p")))
    q1 + q2 -> p

Where above, we probably want ``(q1 + q2) -> p``.

The solution to this case is to set the precedence of the operator, using
the :paramref:`.Operators.op.precedence` parameter, to a high
number, where 100 is the maximum value, and the highest number used by any
SQLAlchemy operator is currently 15::

    >>> print((column("q1") + column("q2")).op("->", precedence=100)(column("p")))
    (q1 + q2) -> p

We can also usually force parenthesization around a binary expression (e.g.
an expression that has left/right operands and an operator) using the
:meth:`_expression.ColumnElement.self_group` method::

    >>> print((column("q1") + column("q2")).self_group().op("->")(column("p")))
    (q1 + q2) -> p

Why are the parentheses rules like this?
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

A lot of databases barf when there are excessive parenthesis or when
parenthesis are in unusual places they doesn't expect, so SQLAlchemy does not
generate parenthesis based on groupings, it uses operator precedence and if the
operator is known to be associative, so that parenthesis are generated
minimally. Otherwise, an expression like::

    column("a") & column("b") & column("c") & column("d")

would produce::

    (((a AND b) AND c) AND d)

which is fine but would probably annoy people (and be reported as a bug). In
other cases, it leads to things that are more likely to confuse databases or at
the very least readability, such as::

  column("q", ARRAY(Integer, dimensions=2))[5][6]

would produce::

    ((q[5])[6])

There are also some edge cases where we get things like ``"(x) = 7"`` and databases
really don't like that either.  So parenthesization doesn't naively
parenthesize, it uses operator precedence and associativity to determine
groupings.

For :meth:`.Operators.op`, the value of precedence defaults to zero.

What if we defaulted the value of :paramref:`.Operators.op.precedence` to 100,
e.g. the highest?  Then this expression makes more parenthesis, but is
otherwise OK, that is, these two are equivalent::

    >>> print((column("q") - column("y")).op("+", precedence=100)(column("z")))
    (q - y) + z
    >>> print((column("q") - column("y")).op("+")(column("z")))
    q - y + z

but these two are not::

    >>> print(column("q") - column("y").op("+", precedence=100)(column("z")))
    q - y + z
    >>> print(column("q") - column("y").op("+")(column("z")))
    q - (y + z)

For now, it's not clear that as long as we are doing parenthesization based on
operator precedence and associativity, if there is really a way to parenthesize
automatically for a generic operator with no precedence given that is going to
work in all cases, because sometimes you want a custom op to have a lower
precedence than the other operators and sometimes you want it to be higher.

It is possible that maybe if the "binary" expression above forced the use of
the ``self_group()`` method when ``op()`` is called, making the assumption that
a compound expression on the left side can always be parenthesized harmlessly.
Perhaps this change can be made at some point, however for the time being
keeping the parenthesization rules more internally consistent seems to be
the safer approach.