summaryrefslogtreecommitdiff
path: root/doc/build/core/defaults.rst
blob: ef5ad2081590f58dcbc0a518db6b4f5aa5874556 (plain)
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
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
.. currentmodule:: sqlalchemy.schema

.. _metadata_defaults_toplevel:

.. _metadata_defaults:

Column INSERT/UPDATE Defaults
=============================

Column INSERT and UPDATE defaults refer to functions that create a **default
value** for a particular column in a row as an INSERT or UPDATE statement is
proceeding against that row, in the case where **no value was provided to the
INSERT or UPDATE statement for that column**.  That is, if a table has a column
called "timestamp", and an INSERT statement proceeds which does not include a
value for this column, an INSERT default would create a new value, such as
the current time, that is used as the value to be INSERTed into the "timestamp"
column.  If the statement *does* include a value  for this column, then the
default does *not* take place.

Column defaults can be server-side functions or constant values which are
defined in the database along with the schema in :term:`DDL`, or as SQL
expressions which are rendered directly within an INSERT or UPDATE statement
emitted by SQLAlchemy; they may also be client-side Python functions or
constant values which are invoked by SQLAlchemy before data is passed to the
database.

.. note::

    A column default handler should not be confused with a construct that
    intercepts and modifies incoming values for INSERT and UPDATE statements
    which *are* provided to the statement as it is invoked.  This is known
    as :term:`data marshalling`, where a column value is modified in some way
    by the application before being sent to the database.  SQLAlchemy provides
    a few means of achieving this which include using :ref:`custom datatypes
    <types_typedecorator>`, :ref:`SQL execution events <core_sql_events>` and
    in the ORM :ref:`custom  validators <simple_validators>` as well as
    :ref:`attribute events <orm_attribute_events>`.    Column defaults are only
    invoked when there is **no value present** for a column in a SQL
    :term:`DML` statement.


SQLAlchemy provides an array of features regarding default generation
functions which take place for non-present values during INSERT and UPDATE
statements. Options include:

* Scalar values used as defaults during INSERT and UPDATE operations
* Python functions which execute upon INSERT and UPDATE operations
* SQL expressions which are embedded in INSERT statements (or in some cases execute beforehand)
* SQL expressions which are embedded in UPDATE statements
* Server side default values used during INSERT
* Markers for server-side triggers used during UPDATE

The general rule for all insert/update defaults is that they only take effect
if no value for a particular column is passed as an ``execute()`` parameter;
otherwise, the given value is used.

Scalar Defaults
---------------

The simplest kind of default is a scalar value used as the default value of a column::

    Table("mytable", metadata_obj, Column("somecolumn", Integer, default=12))

Above, the value "12" will be bound as the column value during an INSERT if no
other value is supplied.

A scalar value may also be associated with an UPDATE statement, though this is
not very common (as UPDATE statements are usually looking for dynamic
defaults)::

    Table("mytable", metadata_obj, Column("somecolumn", Integer, onupdate=25))

Python-Executed Functions
-------------------------

The :paramref:`_schema.Column.default` and :paramref:`_schema.Column.onupdate` keyword arguments also accept Python
functions. These functions are invoked at the time of insert or update if no
other value for that column is supplied, and the value returned is used for
the column's value. Below illustrates a crude "sequence" that assigns an
incrementing counter to a primary key column::

    # a function which counts upwards
    i = 0


    def mydefault():
        global i
        i += 1
        return i


    t = Table(
        "mytable",
        metadata_obj,
        Column("id", Integer, primary_key=True, default=mydefault),
    )

It should be noted that for real "incrementing sequence" behavior, the
built-in capabilities of the database should normally be used, which may
include sequence objects or other autoincrementing capabilities. For primary
key columns, SQLAlchemy will in most cases use these capabilities
automatically. See the API documentation for
:class:`~sqlalchemy.schema.Column` including the :paramref:`_schema.Column.autoincrement` flag, as
well as the section on :class:`~sqlalchemy.schema.Sequence` later in this
chapter for background on standard primary key generation techniques.

To illustrate onupdate, we assign the Python ``datetime`` function ``now`` to
the :paramref:`_schema.Column.onupdate` attribute::

    import datetime

    t = Table(
        "mytable",
        metadata_obj,
        Column("id", Integer, primary_key=True),
        # define 'last_updated' to be populated with datetime.now()
        Column("last_updated", DateTime, onupdate=datetime.datetime.now),
    )

When an update statement executes and no value is passed for ``last_updated``,
the ``datetime.datetime.now()`` Python function is executed and its return
value used as the value for ``last_updated``. Notice that we provide ``now``
as the function itself without calling it (i.e. there are no parenthesis
following) - SQLAlchemy will execute the function at the time the statement
executes.

.. _context_default_functions:

Context-Sensitive Default Functions
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

The Python functions used by :paramref:`_schema.Column.default` and
:paramref:`_schema.Column.onupdate` may also make use of the current statement's
context in order to determine a value. The `context` of a statement is an
internal SQLAlchemy object which contains all information about the statement
being executed, including its source expression, the parameters associated with
it and the cursor. The typical use case for this context with regards to
default generation is to have access to the other values being inserted or
updated on the row. To access the context, provide a function that accepts a
single ``context`` argument::

    def mydefault(context):
        return context.get_current_parameters()["counter"] + 12


    t = Table(
        "mytable",
        metadata_obj,
        Column("counter", Integer),
        Column("counter_plus_twelve", Integer, default=mydefault, onupdate=mydefault),
    )

The above default generation function is applied so that it will execute for
all INSERT and UPDATE statements where a value for ``counter_plus_twelve`` was
otherwise not provided, and the value will be that of whatever value is present
in the execution for the ``counter`` column, plus the number 12.

For a single statement that is being executed using "executemany" style, e.g.
with multiple parameter sets passed to :meth:`_engine.Connection.execute`, the
user-defined function is called once for each set of parameters. For the use case of
a multi-valued :class:`_expression.Insert` construct (e.g. with more than one VALUES
clause set up via the :meth:`_expression.Insert.values` method), the user-defined function
is also called once for each set of parameters.

When the function is invoked, the special method
:meth:`.DefaultExecutionContext.get_current_parameters` is available from
the context object (an subclass of :class:`.DefaultExecutionContext`).  This
method returns a dictionary of column-key to values that represents the
full set of values for the INSERT or UPDATE statement.   In the case of a
multi-valued INSERT construct, the subset of parameters that corresponds to
the individual VALUES clause is isolated from the full parameter dictionary
and returned alone.

.. versionadded:: 1.2

    Added :meth:`.DefaultExecutionContext.get_current_parameters` method,
    which improves upon the still-present
    :attr:`.DefaultExecutionContext.current_parameters` attribute
    by offering the service of organizing multiple VALUES clauses
    into individual parameter dictionaries.

.. _defaults_client_invoked_sql:

Client-Invoked SQL Expressions
------------------------------

The :paramref:`_schema.Column.default` and :paramref:`_schema.Column.onupdate` keywords may
also be passed SQL expressions, which are in most cases rendered inline within the
INSERT or UPDATE statement::

    t = Table(
        "mytable",
        metadata_obj,
        Column("id", Integer, primary_key=True),
        # define 'create_date' to default to now()
        Column("create_date", DateTime, default=func.now()),
        # define 'key' to pull its default from the 'keyvalues' table
        Column(
            "key",
            String(20),
            default=select(keyvalues.c.key).where(keyvalues.c.type="type1"),
        ),
        # define 'last_modified' to use the current_timestamp SQL function on update
        Column("last_modified", DateTime, onupdate=func.utc_timestamp()),
    )

Above, the ``create_date`` column will be populated with the result of the
``now()`` SQL function (which, depending on backend, compiles into ``NOW()``
or ``CURRENT_TIMESTAMP`` in most cases) during an INSERT statement, and the
``key`` column with the result of a SELECT subquery from another table. The
``last_modified`` column will be populated with the value of
the SQL ``UTC_TIMESTAMP()`` MySQL function when an UPDATE statement is
emitted for this table.

.. note::

    When using SQL functions with the :attr:`.func` construct, we "call" the
    named function, e.g. with parenthesis as in ``func.now()``.   This differs
    from when we specify a Python callable as a default such as
    ``datetime.datetime``, where we pass the function itself, but we don't
    invoke it ourselves.   In the case of a SQL function, invoking
    ``func.now()`` returns the SQL expression object that will render the
    "NOW" function into the SQL being emitted.

Default and update SQL expressions specified by :paramref:`_schema.Column.default` and
:paramref:`_schema.Column.onupdate` are invoked explicitly by SQLAlchemy when an
INSERT or UPDATE statement occurs, typically rendered inline within the DML
statement except in certain cases listed below.   This is different than a
"server side" default, which is part of the table's DDL definition, e.g. as
part of the "CREATE TABLE" statement, which are likely more common.   For
server side defaults, see the next section :ref:`server_defaults`.

When a SQL expression indicated by :paramref:`_schema.Column.default` is used with
primary key columns, there are some cases where SQLAlchemy must "pre-execute"
the default generation SQL function, meaning it is invoked in a separate SELECT
statement, and the resulting value is passed as a parameter to the INSERT.
This only occurs for primary key columns for an INSERT statement that is being
asked to return this primary key value, where RETURNING or ``cursor.lastrowid``
may not be used.   An :class:`_expression.Insert` construct that specifies the
:paramref:`~.expression.insert.inline` flag will always render default expressions
inline.

When the statement is executed with a single set of parameters (that is, it is
not an "executemany" style execution), the returned
:class:`~sqlalchemy.engine.CursorResult` will contain a collection accessible
via :meth:`_engine.CursorResult.postfetch_cols` which contains a list of all
:class:`~sqlalchemy.schema.Column` objects which had an inline-executed
default. Similarly, all parameters which were bound to the statement, including
all Python and SQL expressions which were pre-executed, are present in the
:meth:`_engine.CursorResult.last_inserted_params` or
:meth:`_engine.CursorResult.last_updated_params` collections on
:class:`~sqlalchemy.engine.CursorResult`. The
:attr:`_engine.CursorResult.inserted_primary_key` collection contains a list of primary
key values for the row inserted (a list so that single-column and
composite-column primary keys are represented in the same format).

.. _server_defaults:

Server-invoked DDL-Explicit Default Expressions
-----------------------------------------------

A variant on the SQL expression default is the :paramref:`_schema.Column.server_default`, which gets
placed in the CREATE TABLE statement during a :meth:`_schema.Table.create` operation:

.. sourcecode:: python+sql

    t = Table(
        "test",
        metadata_obj,
        Column("abc", String(20), server_default="abc"),
        Column("created_at", DateTime, server_default=func.sysdate()),
        Column("index_value", Integer, server_default=text("0")),
    )

A create call for the above table will produce:

.. sourcecode:: sql

    CREATE TABLE test (
        abc varchar(20) default 'abc',
        created_at datetime default sysdate,
        index_value integer default 0
    )

The above example illustrates the two typical use cases for :paramref:`_schema.Column.server_default`,
that of the SQL function (SYSDATE in the above example) as well as a server-side constant
value (the integer "0" in the above example).  It is advisable to use the
:func:`_expression.text` construct for any literal SQL values as opposed to passing the
raw value, as SQLAlchemy does not typically perform any quoting or escaping on
these values.

Like client-generated expressions, :paramref:`_schema.Column.server_default` can accommodate
SQL expressions in general, however it is expected that these will usually be simple
functions and expressions, and not the more complex cases like an embedded SELECT.


.. _triggered_columns:

Marking Implicitly Generated Values, timestamps, and Triggered Columns
----------------------------------------------------------------------

Columns which generate a new value on INSERT or UPDATE based on other
server-side database mechanisms, such as database-specific auto-generating
behaviors such as seen with TIMESTAMP columns on some platforms, as well as
custom triggers that invoke upon INSERT or UPDATE to generate a new value,
may be called out using :class:`.FetchedValue` as a marker::

    from sqlalchemy.schema import FetchedValue

    t = Table(
        "test",
        metadata_obj,
        Column("id", Integer, primary_key=True),
        Column("abc", TIMESTAMP, server_default=FetchedValue()),
        Column("def", String(20), server_onupdate=FetchedValue()),
    )

The :class:`.FetchedValue` indicator does not affect the rendered DDL for the
CREATE TABLE.  Instead, it marks the column as one that will have a new value
populated by the database during the process of an INSERT or UPDATE statement,
and for supporting  databases may be used to indicate that the column should be
part of a RETURNING or OUTPUT clause for the statement.    Tools such as the
SQLAlchemy ORM then make use of this marker in order to know how to get at the
value of the column after such an operation.   In particular, the
:meth:`.ValuesBase.return_defaults` method can be used with an :class:`_expression.Insert`
or :class:`_expression.Update` construct to indicate that these values should be
returned.

For details on using :class:`.FetchedValue` with the ORM, see
:ref:`orm_server_defaults`.

.. warning:: The :paramref:`_schema.Column.server_onupdate` directive
    **does not** currently produce MySQL's
    "ON UPDATE CURRENT_TIMESTAMP()" clause.  See
    :ref:`mysql_timestamp_onupdate` for background on how to produce
    this clause.


.. seealso::

    :ref:`orm_server_defaults`

.. _defaults_sequences:

Defining Sequences
------------------

SQLAlchemy represents database sequences using the
:class:`~sqlalchemy.schema.Sequence` object, which is considered to be a
special case of "column default". It only has an effect on databases which have
explicit support for sequences, which among SQLAlchemy's included dialects
includes PostgreSQL, Oracle, MS SQL Server, and MariaDB.  The
:class:`~sqlalchemy.schema.Sequence` object is otherwise ignored.

.. tip::

    In newer database engines, the :class:`.Identity` construct should likely
    be preferred vs. :class:`.Sequence` for generation of integer primary key
    values. See the section :ref:`identity_ddl` for background on this
    construct.

The :class:`~sqlalchemy.schema.Sequence` may be placed on any column as a
"default" generator to be used during INSERT operations, and can also be
configured to fire off during UPDATE operations if desired. It is most
commonly used in conjunction with a single integer primary key column::

    table = Table(
        "cartitems",
        metadata_obj,
        Column(
            "cart_id",
            Integer,
            Sequence("cart_id_seq", start=1),
            primary_key=True,
        ),
        Column("description", String(40)),
        Column("createdate", DateTime()),
    )

Where above, the table ``cartitems`` is associated with a sequence named
``cart_id_seq``.   Emitting :meth:`.MetaData.create_all` for the above
table will include:

.. sourcecode:: sql

    CREATE SEQUENCE cart_id_seq START WITH 1

    CREATE TABLE cartitems (
      cart_id INTEGER NOT NULL,
      description VARCHAR(40),
      createdate TIMESTAMP WITHOUT TIME ZONE,
      PRIMARY KEY (cart_id)
    )

.. tip::

  When using tables with explicit schema names (detailed at
  :ref:`schema_table_schema_name`), the configured schema of the :class:`.Table`
  is **not** automatically shared by an embedded :class:`.Sequence`, instead,
  specify :paramref:`.Sequence.schema`::

    Sequence("cart_id_seq", start=1, schema="some_schema")

  The :class:`.Sequence` may also be made to automatically make use of the
  :paramref:`.MetaData.schema` setting on the :class:`.MetaData` in use;
  see :ref:`sequence_metadata` for background.

When :class:`_dml.Insert` DML constructs are invoked against the ``cartitems``
table, without an explicit value passed for the ``cart_id`` column, the
``cart_id_seq`` sequence will be used to generate a value on participating
backends. Typically, the sequence function is embedded in the INSERT statement,
which is combined with RETURNING so that the newly generated value can be
returned to the Python process:

.. sourcecode:: sql

    INSERT INTO cartitems (cart_id, description, createdate)
    VALUES (next_val(cart_id_seq), 'some description', '2015-10-15 12:00:15')
    RETURNING cart_id

When using :meth:`.Connection.execute` to invoke an :class:`_dml.Insert` construct,
newly generated primary key identifiers, including but not limited to those
generated using :class:`.Sequence`, are available from the :class:`.CursorResult`
construct using the :attr:`.CursorResult.inserted_primary_key` attribute.

When the :class:`~sqlalchemy.schema.Sequence` is associated with a
:class:`_schema.Column` as its **Python-side** default generator, the
:class:`.Sequence` will also be subject to "CREATE SEQUENCE" and "DROP
SEQUENCE" DDL when similar DDL is emitted for the owning :class:`_schema.Table`,
such as when using :meth:`.MetaData.create_all` to generate DDL for a series
of tables.

The :class:`.Sequence` may also be associated with a
:class:`.MetaData` construct directly.  This allows the :class:`.Sequence`
to be used in more than one :class:`.Table` at a time and also allows the
:paramref:`.MetaData.schema` parameter to be inherited.  See the section
:ref:`sequence_metadata` for background.

Associating a Sequence on a SERIAL column
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

PostgreSQL's SERIAL datatype is an auto-incrementing type that implies
the implicit creation of a PostgreSQL sequence when CREATE TABLE is emitted.
The :class:`.Sequence` construct, when indicated for a :class:`_schema.Column`,
may indicate that it should not be used in this specific case by specifying
a value of ``True`` for the :paramref:`.Sequence.optional` parameter.
This allows the given :class:`.Sequence` to be used for backends that have no
alternative primary key generation system but to ignore it for backends
such as PostgreSQL which will automatically generate a sequence for a particular
column::

    table = Table(
        "cartitems",
        metadata_obj,
        Column(
            "cart_id",
            Integer,
            # use an explicit Sequence where available, but not on
            # PostgreSQL where SERIAL will be used
            Sequence("cart_id_seq", start=1, optional=True),
            primary_key=True,
        ),
        Column("description", String(40)),
        Column("createdate", DateTime()),
    )

In the above example, ``CREATE TABLE`` for PostgreSQL will make use of the
``SERIAL`` datatype for the ``cart_id`` column, and the ``cart_id_seq``
sequence will be ignored.  However on Oracle, the ``cart_id_seq`` sequence
will be created explicitly.

.. tip::

    This particular interaction of SERIAL and SEQUENCE is fairly legacy, and
    as in other cases, using :class:`.Identity` instead will simplify the
    operation to simply use ``IDENTITY`` on all supported backends.


Executing a Sequence Standalone
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

A SEQUENCE is a first class schema object in SQL and can be used to generate
values independently in the database.   If you have a :class:`.Sequence`
object, it can be invoked with its "next value" instruction by
passing it directly to a SQL execution method::

    with my_engine.connect() as conn:
        seq = Sequence("some_sequence", start=1)
        nextid = conn.execute(seq)

In order to embed the "next value" function of a :class:`.Sequence`
inside of a SQL statement like a SELECT or INSERT, use the :meth:`.Sequence.next_value`
method, which will render at statement compilation time a SQL function that is
appropriate for the target backend:

.. sourcecode:: pycon+sql

    >>> my_seq = Sequence("some_sequence", start=1)
    >>> stmt = select(my_seq.next_value())
    >>> print(stmt.compile(dialect=postgresql.dialect()))
    {printsql}SELECT nextval('some_sequence') AS next_value_1

.. _sequence_metadata:

Associating a Sequence with the MetaData
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

For a :class:`.Sequence` that is to be associated with arbitrary
:class:`.Table` objects, the :class:`.Sequence` may be associated with
a particular :class:`_schema.MetaData`, using the
:paramref:`.Sequence.metadata` parameter::

    seq = Sequence("my_general_seq", metadata=metadata_obj, start=1)

Such a sequence can then be associated with columns in the usual way::

    table = Table(
        "cartitems",
        metadata_obj,
        seq,
        Column("description", String(40)),
        Column("createdate", DateTime()),
    )

In the above example, the :class:`.Sequence` object is treated as an
independent schema construct that can exist on its own or be shared among
tables.

Explicitly associating the :class:`.Sequence` with :class:`_schema.MetaData`
allows for the following behaviors:

* The :class:`.Sequence` will inherit the :paramref:`_schema.MetaData.schema`
  parameter specified to the target :class:`_schema.MetaData`, which
  affects the production of CREATE / DROP DDL as well as how the
  :meth:`.Sequence.next_value` function is rendered in SQL statements.

* The :meth:`_schema.MetaData.create_all` and :meth:`_schema.MetaData.drop_all`
  methods will emit CREATE / DROP for this :class:`.Sequence`,
  even if the :class:`.Sequence` is not associated with any
  :class:`_schema.Table` / :class:`_schema.Column` that's a member of this
  :class:`_schema.MetaData`.

Associating a Sequence as the Server Side Default
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

.. note:: The following technique is known to work only with the PostgreSQL
   database.  It does not work with Oracle.

The preceding sections illustrate how to associate a :class:`.Sequence` with a
:class:`_schema.Column` as the **Python side default generator**::

    Column(
        "cart_id",
        Integer,
        Sequence("cart_id_seq", metadata=metadata_obj, start=1),
        primary_key=True,
    )

In the above case, the :class:`.Sequence` will automatically be subject
to CREATE SEQUENCE / DROP SEQUENCE DDL when the related :class:`_schema.Table`
is subject to CREATE / DROP.  However, the sequence will **not** be present
as the server-side default for the column when CREATE TABLE is emitted.

If we want the sequence to be used as a server-side default,
meaning it takes place even if we emit INSERT commands to the table from
the SQL command line, we can use the :paramref:`_schema.Column.server_default`
parameter in conjunction with the value-generation function of the
sequence, available from the :meth:`.Sequence.next_value` method.  Below
we illustrate the same :class:`.Sequence` being associated with the
:class:`_schema.Column` both as the Python-side default generator as well as
the server-side default generator::

    cart_id_seq = Sequence("cart_id_seq", metadata=metadata_obj, start=1)
    table = Table(
        "cartitems",
        metadata_obj,
        Column(
            "cart_id",
            Integer,
            cart_id_seq,
            server_default=cart_id_seq.next_value(),
            primary_key=True,
        ),
        Column("description", String(40)),
        Column("createdate", DateTime()),
    )

or with the ORM::

    class CartItem(Base):
        __tablename__ = "cartitems"

        cart_id_seq = Sequence("cart_id_seq", metadata=Base.metadata, start=1)
        cart_id = Column(
            Integer, cart_id_seq, server_default=cart_id_seq.next_value(), primary_key=True
        )
        description = Column(String(40))
        createdate = Column(DateTime)

When the "CREATE TABLE" statement is emitted, on PostgreSQL it would be
emitted as:

.. sourcecode:: sql

    CREATE TABLE cartitems (
        cart_id INTEGER DEFAULT nextval('cart_id_seq') NOT NULL,
        description VARCHAR(40),
        createdate TIMESTAMP WITHOUT TIME ZONE,
        PRIMARY KEY (cart_id)
    )

Placement of the :class:`.Sequence` in both the Python-side and server-side
default generation contexts ensures that the "primary key fetch" logic
works in all cases.  Typically, sequence-enabled databases also support
RETURNING for INSERT statements, which is used automatically by SQLAlchemy
when emitting this statement.  However if RETURNING is not used for a particular
insert, then SQLAlchemy would prefer to "pre-execute" the sequence outside
of the INSERT statement itself, which only works if the sequence is
included as the Python-side default generator function.

The example also associates the :class:`.Sequence` with the enclosing
:class:`_schema.MetaData` directly, which again ensures that the :class:`.Sequence`
is fully associated with the parameters of the :class:`_schema.MetaData` collection
including the default schema, if any.

.. seealso::

    :ref:`postgresql_sequences` - in the PostgreSQL dialect documentation

    :ref:`oracle_returning` - in the Oracle dialect documentation

.. _computed_ddl:

Computed Columns (GENERATED ALWAYS AS)
--------------------------------------

.. versionadded:: 1.3.11

The :class:`.Computed` construct allows a :class:`_schema.Column` to be declared in
DDL as a "GENERATED ALWAYS AS" column, that is, one which has a value that is
computed by the database server.    The construct accepts a SQL expression
typically declared textually using a string or the :func:`_expression.text` construct, in
a similar manner as that of :class:`.CheckConstraint`.   The SQL expression is
then interpreted by the database server in order to determine the value for the
column within a row.

Example::

    from sqlalchemy import Table, Column, MetaData, Integer, Computed

    metadata_obj = MetaData()

    square = Table(
        "square",
        metadata_obj,
        Column("id", Integer, primary_key=True),
        Column("side", Integer),
        Column("area", Integer, Computed("side * side")),
        Column("perimeter", Integer, Computed("4 * side")),
    )

The DDL for the ``square`` table when run on a PostgreSQL 12 backend will look
like:

.. sourcecode:: sql

    CREATE TABLE square (
        id SERIAL NOT NULL,
        side INTEGER,
        area INTEGER GENERATED ALWAYS AS (side * side) STORED,
        perimeter INTEGER GENERATED ALWAYS AS (4 * side) STORED,
        PRIMARY KEY (id)
    )

Whether the value is persisted upon INSERT and UPDATE, or if it is calculated
on fetch, is an implementation detail of the database; the former is known as
"stored" and the latter is known as "virtual".  Some database implementations
support both, but some only support one or the other.  The optional
:paramref:`.Computed.persisted` flag may be specified as ``True`` or ``False``
to indicate if the "STORED" or "VIRTUAL" keyword should be rendered in DDL,
however this will raise an error if the keyword is not supported by the target
backend; leaving it unset will use  a working default for the target backend.

The :class:`.Computed` construct is a subclass of the :class:`.FetchedValue`
object, and will set itself up as both the "server default" and "server
onupdate" generator for the target :class:`_schema.Column`, meaning it will be treated
as a default generating column when INSERT and UPDATE statements are generated,
as well as that it will be fetched as a generating column when using the ORM.
This includes that it will be part of the RETURNING clause of the database
for databases which support RETURNING and the generated values are to be
eagerly fetched.

.. note:: A :class:`_schema.Column` that is defined with the :class:`.Computed`
   construct may not store any value outside of that which the server applies
   to it;  SQLAlchemy's behavior when a value is passed for such a column
   to be written in INSERT or UPDATE is currently that the value will be
   ignored.

"GENERATED ALWAYS AS" is currently known to be supported by:

* MySQL version 5.7 and onwards

* MariaDB 10.x series and onwards

* PostgreSQL as of version 12

* Oracle - with the caveat that RETURNING does not work correctly with UPDATE
  (a warning will be emitted to this effect when the UPDATE..RETURNING that
  includes a computed column is rendered)

* Microsoft SQL Server

* SQLite as of version 3.31

When :class:`.Computed` is used with an unsupported backend, if the target
dialect does not support it, a :class:`.CompileError` is raised when attempting
to render the construct.  Otherwise, if the dialect supports it but the
particular database server version in use does not, then a subclass of
:class:`.DBAPIError`, usually :class:`.OperationalError`, is raised when the
DDL is emitted to the database.

.. seealso::

    :class:`.Computed`

.. _identity_ddl:

Identity Columns (GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY)
-----------------------------------------------------------------

.. versionadded:: 1.4

The :class:`.Identity` construct allows a :class:`_schema.Column` to be declared
as an identity column and rendered in DDL as "GENERATED { ALWAYS | BY DEFAULT }
AS IDENTITY".  An identity column has its value automatically generated by the
database server using an incrementing (or decrementing) sequence. The construct
shares most of its option to control the database behaviour with
:class:`.Sequence`.

Example::

    from sqlalchemy import Table, Column, MetaData, Integer, Identity, String

    metadata_obj = MetaData()

    data = Table(
        "data",
        metadata_obj,
        Column("id", Integer, Identity(start=42, cycle=True), primary_key=True),
        Column("data", String),
    )

The DDL for the ``data`` table when run on a PostgreSQL 12 backend will look
like:

.. sourcecode:: sql

    CREATE TABLE data (
        id INTEGER GENERATED BY DEFAULT AS IDENTITY (START WITH 42 CYCLE) NOT NULL,
        data VARCHAR,
        PRIMARY KEY (id)
    )

The database will generate a value for the ``id`` column upon insert,
starting from ``42``, if the statement did not already contain a value for
the ``id`` column.
An identity column can also require that the database generates the value
of the column, ignoring the value passed with the statement or raising an
error, depending on the backend. To activate this mode, set the parameter
:paramref:`_schema.Identity.always` to ``True`` in the
:class:`.Identity` construct. Updating the previous
example to include this parameter will generate the following DDL:

.. sourcecode:: sql

    CREATE TABLE data (
        id INTEGER GENERATED ALWAYS AS IDENTITY (START WITH 42 CYCLE) NOT NULL,
        data VARCHAR,
        PRIMARY KEY (id)
    )

The :class:`.Identity` construct is a subclass of the :class:`.FetchedValue`
object, and will set itself up as the "server default" generator for the
target :class:`_schema.Column`, meaning it will be treated
as a default generating column when INSERT statements are generated,
as well as that it will be fetched as a generating column when using the ORM.
This includes that it will be part of the RETURNING clause of the database
for databases which support RETURNING and the generated values are to be
eagerly fetched.

The :class:`.Identity` construct is currently known to be supported by:

* PostgreSQL as of version 10.

* Oracle as of version 12. It also supports passing ``always=None`` to
  enable the default generated mode and the parameter ``on_null=True`` to
  specify "ON NULL" in conjunction with a "BY DEFAULT" identity column.

* Microsoft SQL Server. MSSQL uses a custom syntax that only supports the
  ``start`` and ``increment`` parameters, and ignores all other.

When :class:`.Identity` is used with an unsupported backend, it is ignored,
and the default SQLAlchemy logic for autoincrementing columns is used.

An error is raised when a :class:`_schema.Column` specifies both an
:class:`.Identity` and also sets :paramref:`_schema.Column.autoincrement`
to ``False``.

.. seealso::

    :class:`.Identity`


Default Objects API
-------------------

.. autoclass:: Computed
    :members:


.. autoclass:: ColumnDefault


.. autoclass:: DefaultClause


.. autoclass:: DefaultGenerator


.. autoclass:: FetchedValue


.. autoclass:: Sequence
    :members:


.. autoclass:: Identity
    :members: