summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
-rw-r--r--doc/build/changelog/changelog_10.rst19
-rw-r--r--doc/build/changelog/migration_10.rst83
-rw-r--r--lib/sqlalchemy/engine/default.py9
-rw-r--r--lib/sqlalchemy/sql/crud.py83
-rw-r--r--lib/sqlalchemy/sql/dml.py6
-rw-r--r--lib/sqlalchemy/testing/assertions.py3
-rw-r--r--test/sql/test_defaults.py22
-rw-r--r--test/sql/test_insert.py136
8 files changed, 296 insertions, 65 deletions
diff --git a/doc/build/changelog/changelog_10.rst b/doc/build/changelog/changelog_10.rst
index 7f9fbff91..5d8bb7b68 100644
--- a/doc/build/changelog/changelog_10.rst
+++ b/doc/build/changelog/changelog_10.rst
@@ -23,6 +23,25 @@
on compatibility concerns, see :doc:`/changelog/migration_10`.
.. change::
+ :tags: bug, sql
+ :tickets: 3288
+
+ The multi-values version of :meth:`.Insert.values` has been
+ repaired to work more usefully with tables that have Python-
+ side default values and/or functions, as well as server-side
+ defaults. The feature will now work with a dialect that uses
+ "positional" parameters; a Python callable will also be
+ invoked individually for each row just as is the case with an
+ "executemany" style invocation; a server- side default column
+ will no longer implicitly receive the value explicitly
+ specified for the first row, instead refusing to invoke
+ without an explicit value.
+
+ .. seealso::
+
+ :ref:`bug_3288`
+
+ .. change::
:tags: feature, general
Structural memory use has been improved via much more significant use
diff --git a/doc/build/changelog/migration_10.rst b/doc/build/changelog/migration_10.rst
index 52179a323..bd878f4cb 100644
--- a/doc/build/changelog/migration_10.rst
+++ b/doc/build/changelog/migration_10.rst
@@ -1362,6 +1362,89 @@ be qualified with :func:`.text` or similar.
:ticket:`2992`
+.. _bug_3288:
+
+Python-side defaults invoked for each row invidually when using a multivalued insert
+------------------------------------------------------------------------------------
+
+Support for Python-side column defaults when using the multi-valued
+version of :meth:`.Insert.values` were essentially not implemented, and
+would only work "by accident" in specific situations, when the dialect in
+use was using a non-positional (e.g. named) style of bound parameter, and
+when it was not necessary that a Python-side callable be invoked for each
+row.
+
+The feature has been overhauled so that it works more similarly to
+that of an "executemany" style of invocation::
+
+ import itertools
+
+ counter = itertools.count(1)
+ t = Table(
+ 'my_table', metadata,
+ Column('id', Integer, default=lambda: next(counter)),
+ Column('data', String)
+ )
+
+ conn.execute(t.insert().values([
+ {"data": "d1"},
+ {"data": "d2"},
+ {"data": "d3"},
+ ]))
+
+The above example will invoke ``next(counter)`` for each row individually
+as would be expected::
+
+ INSERT INTO my_table (id, data) VALUES (?, ?), (?, ?), (?, ?)
+ (1, 'd1', 2, 'd2', 3, 'd3')
+
+Previously, a positional dialect would fail as a bind would not be generated
+for additional positions::
+
+ Incorrect number of bindings supplied. The current statement uses 6,
+ and there are 4 supplied.
+ [SQL: u'INSERT INTO my_table (id, data) VALUES (?, ?), (?, ?), (?, ?)']
+ [parameters: (1, 'd1', 'd2', 'd3')]
+
+And with a "named" dialect, the same value for "id" would be re-used in
+each row (hence this change is backwards-incompatible with a system that
+relied on this)::
+
+ INSERT INTO my_table (id, data) VALUES (:id, :data_0), (:id, :data_1), (:id, :data_2)
+ {u'data_2': 'd3', u'data_1': 'd2', u'data_0': 'd1', 'id': 1}
+
+The system will also refuse to invoke a "server side" default as inline-rendered
+SQL, since it cannot be guaranteed that a server side default is compatible
+with this. If the VALUES clause renders for a specific column, then a Python-side
+value is required; if an omitted value only refers to a server-side default,
+an exception is raised::
+
+ t = Table(
+ 'my_table', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('data', String, server_default='some default')
+ )
+
+ conn.execute(t.insert().values([
+ {"data": "d1"},
+ {"data": "d2"},
+ {},
+ ]))
+
+will raise::
+
+ sqlalchemy.exc.CompileError: INSERT value for column my_table.data is
+ explicitly rendered as a boundparameter in the VALUES clause; a
+ Python-side value or SQL expression is required
+
+Previously, the value "d1" would be copied into that of the third
+row (but again, only with named format!)::
+
+ INSERT INTO my_table (data) VALUES (:data_0), (:data_1), (:data_0)
+ {u'data_1': 'd2', u'data_0': 'd1'}
+
+:ticket:`3288`
+
.. _change_3163:
Event listeners can not be added or removed from within that event's runner
diff --git a/lib/sqlalchemy/engine/default.py b/lib/sqlalchemy/engine/default.py
index a5af6ff19..c5b5deece 100644
--- a/lib/sqlalchemy/engine/default.py
+++ b/lib/sqlalchemy/engine/default.py
@@ -956,14 +956,17 @@ class DefaultExecutionContext(interfaces.ExecutionContext):
def _process_executesingle_defaults(self):
key_getter = self.compiled._key_getters_for_crud_column[2]
-
prefetch = self.compiled.prefetch
self.current_parameters = compiled_parameters = \
self.compiled_parameters[0]
for c in prefetch:
if self.isinsert:
- val = self.get_insert_default(c)
+ if c.default and \
+ not c.default.is_sequence and c.default.is_scalar:
+ val = c.default.arg
+ else:
+ val = self.get_insert_default(c)
else:
val = self.get_update_default(c)
@@ -972,6 +975,4 @@ class DefaultExecutionContext(interfaces.ExecutionContext):
del self.current_parameters
-
-
DefaultDialect.execution_ctx_cls = DefaultExecutionContext
diff --git a/lib/sqlalchemy/sql/crud.py b/lib/sqlalchemy/sql/crud.py
index 831d05be1..4bab69df0 100644
--- a/lib/sqlalchemy/sql/crud.py
+++ b/lib/sqlalchemy/sql/crud.py
@@ -116,11 +116,13 @@ def _get_crud_params(compiler, stmt, **kw):
def _create_bind_param(
- compiler, col, value, process=True, required=False, name=None):
+ compiler, col, value, process=True,
+ required=False, name=None, unique=False):
if name is None:
name = col.key
- bindparam = elements.BindParameter(name, value,
- type_=col.type, required=required)
+ bindparam = elements.BindParameter(
+ name, value,
+ type_=col.type, required=required, unique=unique)
bindparam._is_crud = True
if process:
bindparam = bindparam._compiler_dispatch(compiler)
@@ -299,14 +301,49 @@ def _append_param_insert_pk_returning(compiler, stmt, c, values, kw):
)
compiler.returning.append(c)
else:
- values.append(
- (c, _create_bind_param(compiler, c, None))
- )
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values)
else:
compiler.returning.append(c)
+def _create_prefetch_bind_param(compiler, c, values, process=True, name=None):
+ values.append(
+ (c, _create_bind_param(compiler, c, None, process=process, name=name))
+ )
+ compiler.prefetch.append(c)
+
+
+class _multiparam_column(elements.ColumnElement):
+ def __init__(self, original, index):
+ self.key = "%s_%d" % (original.key, index + 1)
+ self.original = original
+ self.default = original.default
+
+ def __eq__(self, other):
+ return isinstance(other, _multiparam_column) and \
+ other.key == self.key and \
+ other.original == self.original
+
+
+def _process_multiparam_default_bind(
+ compiler, c, index, kw):
+
+ if not c.default:
+ raise exc.CompileError(
+ "INSERT value for column %s is explicitly rendered as a bound"
+ "parameter in the VALUES clause; "
+ "a Python-side value or SQL expression is required" % c)
+ elif c.default.is_clause_element:
+ return compiler.process(c.default.arg.self_group(), **kw)
+ else:
+ col = _multiparam_column(c, index)
+ bind = _create_bind_param(
+ compiler, col, None
+ )
+ compiler.prefetch.append(col)
+ return bind
+
+
def _append_param_insert_pk(compiler, stmt, c, values, kw):
if (
(c.default is not None and
@@ -317,11 +354,7 @@ def _append_param_insert_pk(compiler, stmt, c, values, kw):
compiler.dialect.
preexecute_autoincrement_sequences)
):
- values.append(
- (c, _create_bind_param(compiler, c, None))
- )
-
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values)
def _append_param_insert_hasdefault(
@@ -349,10 +382,7 @@ def _append_param_insert_hasdefault(
# don't add primary key column to postfetch
compiler.postfetch.append(c)
else:
- values.append(
- (c, _create_bind_param(compiler, c, None))
- )
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values)
def _append_param_insert_select_hasdefault(
@@ -368,10 +398,7 @@ def _append_param_insert_select_hasdefault(
proc = c.default.arg.self_group()
values.append((c, proc))
else:
- values.append(
- (c, _create_bind_param(compiler, c, None, process=False))
- )
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values, process=False)
def _append_param_update(
@@ -389,10 +416,7 @@ def _append_param_update(
else:
compiler.postfetch.append(c)
else:
- values.append(
- (c, _create_bind_param(compiler, c, None))
- )
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values)
elif c.server_onupdate is not None:
if implicit_return_defaults and \
c in implicit_return_defaults:
@@ -444,13 +468,7 @@ def _get_multitable_params(
)
compiler.postfetch.append(c)
else:
- values.append(
- (c, _create_bind_param(
- compiler, c, None, name=_col_bind_name(c)
- )
- )
- )
- compiler.prefetch.append(c)
+ _create_prefetch_bind_param(compiler, c, values, name=_col_bind_name(c))
elif c.server_onupdate is not None:
compiler.postfetch.append(c)
@@ -469,7 +487,8 @@ def _extend_values_for_multiparams(compiler, stmt, values, kw):
) if elements._is_literal(row[c.key])
else compiler.process(
row[c.key].self_group(), **kw))
- if c.key in row else param
+ if c.key in row else
+ _process_multiparam_default_bind(compiler, c, i, kw)
)
for (c, param) in values_0
]
diff --git a/lib/sqlalchemy/sql/dml.py b/lib/sqlalchemy/sql/dml.py
index 62169319b..38b3b8c44 100644
--- a/lib/sqlalchemy/sql/dml.py
+++ b/lib/sqlalchemy/sql/dml.py
@@ -277,6 +277,12 @@ class ValuesBase(UpdateBase):
deals with an arbitrary number of rows, so the
:attr:`.ResultProxy.inserted_primary_key` accessor does not apply.
+ .. versionchanged:: 1.0.0 A multiple-VALUES INSERT now supports
+ columns with Python side default values and callables in the
+ same way as that of an "executemany" style of invocation; the
+ callable is invoked for each row. See :ref:`bug_3288`
+ for other details.
+
.. seealso::
:ref:`inserts_and_updates` - SQL Expression
diff --git a/lib/sqlalchemy/testing/assertions.py b/lib/sqlalchemy/testing/assertions.py
index 66d1f3cb0..46fcd64b1 100644
--- a/lib/sqlalchemy/testing/assertions.py
+++ b/lib/sqlalchemy/testing/assertions.py
@@ -229,6 +229,7 @@ class AssertsCompiledSQL(object):
def assert_compile(self, clause, result, params=None,
checkparams=None, dialect=None,
checkpositional=None,
+ check_prefetch=None,
use_default_dialect=False,
allow_dialect_select=False,
literal_binds=False):
@@ -289,6 +290,8 @@ class AssertsCompiledSQL(object):
if checkpositional is not None:
p = c.construct_params(params)
eq_(tuple([p[x] for x in c.positiontup]), checkpositional)
+ if check_prefetch is not None:
+ eq_(c.prefetch, check_prefetch)
class ComparesTables(object):
diff --git a/test/sql/test_defaults.py b/test/sql/test_defaults.py
index 10e557b76..b7893d5f1 100644
--- a/test/sql/test_defaults.py
+++ b/test/sql/test_defaults.py
@@ -336,13 +336,7 @@ class DefaultTest(fixtures.TestBase):
[(54, 'imthedefault', f, ts, ts, ctexec, True, False,
12, today, None, 'hi')])
- @testing.fails_on('firebird', 'Data type unknown')
def test_insertmany(self):
- # MySQL-Python 1.2.2 breaks functions in execute_many :(
- if (testing.against('mysql+mysqldb') and
- testing.db.dialect.dbapi.version_info[:3] == (1, 2, 2)):
- return
-
t.insert().execute({}, {}, {})
ctexec = currenttime.scalar()
@@ -356,6 +350,22 @@ class DefaultTest(fixtures.TestBase):
(53, 'imthedefault', f, ts, ts, ctexec, True, False,
12, today, 'py', 'hi')])
+ @testing.requires.multivalues_inserts
+ def test_insert_multivalues(self):
+
+ t.insert().values([{}, {}, {}]).execute()
+
+ ctexec = currenttime.scalar()
+ l = t.select().execute()
+ today = datetime.date.today()
+ eq_(l.fetchall(),
+ [(51, 'imthedefault', f, ts, ts, ctexec, True, False,
+ 12, today, 'py', 'hi'),
+ (52, 'imthedefault', f, ts, ts, ctexec, True, False,
+ 12, today, 'py', 'hi'),
+ (53, 'imthedefault', f, ts, ts, ctexec, True, False,
+ 12, today, 'py', 'hi')])
+
def test_no_embed_in_sql(self):
"""Using a DefaultGenerator, Sequence, DefaultClause
in the columns, where clause of a select, or in the values
diff --git a/test/sql/test_insert.py b/test/sql/test_insert.py
index bd4eaa3e2..8a41d4be7 100644
--- a/test/sql/test_insert.py
+++ b/test/sql/test_insert.py
@@ -1,12 +1,12 @@
#! coding:utf-8
from sqlalchemy import Column, Integer, MetaData, String, Table,\
- bindparam, exc, func, insert, select, column
+ bindparam, exc, func, insert, select, column, text
from sqlalchemy.dialects import mysql, postgresql
from sqlalchemy.engine import default
from sqlalchemy.testing import AssertsCompiledSQL,\
assert_raises_message, fixtures
-
+from sqlalchemy.sql import crud
class _InsertTestBase(object):
@@ -19,6 +19,12 @@ class _InsertTestBase(object):
Table('myothertable', metadata,
Column('otherid', Integer, primary_key=True),
Column('othername', String(30)))
+ Table('table_w_defaults', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('x', Integer, default=10),
+ Column('y', Integer, server_default=text('5')),
+ Column('z', Integer, default=lambda: 10)
+ )
class InsertTest(_InsertTestBase, fixtures.TablesTest, AssertsCompiledSQL):
@@ -565,6 +571,36 @@ class MultirowTest(_InsertTestBase, fixtures.TablesTest, AssertsCompiledSQL):
checkpositional=checkpositional,
dialect=dialect)
+ def test_positional_w_defaults(self):
+ table1 = self.tables.table_w_defaults
+
+ values = [
+ {'id': 1},
+ {'id': 2},
+ {'id': 3}
+ ]
+
+ checkpositional = (1, None, None, 2, None, None, 3, None, None)
+
+ dialect = default.DefaultDialect()
+ dialect.supports_multivalues_insert = True
+ dialect.paramstyle = 'format'
+ dialect.positional = True
+
+ self.assert_compile(
+ table1.insert().values(values),
+ "INSERT INTO table_w_defaults (id, x, z) VALUES "
+ "(%s, %s, %s), (%s, %s, %s), (%s, %s, %s)",
+ checkpositional=checkpositional,
+ check_prefetch=[
+ table1.c.x, table1.c.z,
+ crud._multiparam_column(table1.c.x, 0),
+ crud._multiparam_column(table1.c.z, 0),
+ crud._multiparam_column(table1.c.x, 1),
+ crud._multiparam_column(table1.c.z, 1)
+ ],
+ dialect=dialect)
+
def test_inline_default(self):
metadata = MetaData()
table = Table('sometable', metadata,
@@ -597,6 +633,74 @@ class MultirowTest(_InsertTestBase, fixtures.TablesTest, AssertsCompiledSQL):
checkparams=checkparams,
dialect=postgresql.dialect())
+ def test_python_scalar_default(self):
+ metadata = MetaData()
+ table = Table('sometable', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('data', String),
+ Column('foo', Integer, default=10))
+
+ values = [
+ {'id': 1, 'data': 'data1'},
+ {'id': 2, 'data': 'data2', 'foo': 15},
+ {'id': 3, 'data': 'data3'},
+ ]
+
+ checkparams = {
+ 'id_0': 1,
+ 'id_1': 2,
+ 'id_2': 3,
+ 'data_0': 'data1',
+ 'data_1': 'data2',
+ 'data_2': 'data3',
+ 'foo': None, # evaluated later
+ 'foo_1': 15,
+ 'foo_2': None # evaluated later
+ }
+
+ self.assert_compile(
+ table.insert().values(values),
+ 'INSERT INTO sometable (id, data, foo) VALUES '
+ '(%(id_0)s, %(data_0)s, %(foo)s), '
+ '(%(id_1)s, %(data_1)s, %(foo_1)s), '
+ '(%(id_2)s, %(data_2)s, %(foo_2)s)',
+ checkparams=checkparams,
+ dialect=postgresql.dialect())
+
+ def test_python_fn_default(self):
+ metadata = MetaData()
+ table = Table('sometable', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('data', String),
+ Column('foo', Integer, default=lambda: 10))
+
+ values = [
+ {'id': 1, 'data': 'data1'},
+ {'id': 2, 'data': 'data2', 'foo': 15},
+ {'id': 3, 'data': 'data3'},
+ ]
+
+ checkparams = {
+ 'id_0': 1,
+ 'id_1': 2,
+ 'id_2': 3,
+ 'data_0': 'data1',
+ 'data_1': 'data2',
+ 'data_2': 'data3',
+ 'foo': None, # evaluated later
+ 'foo_1': 15,
+ 'foo_2': None, # evaluated later
+ }
+
+ self.assert_compile(
+ table.insert().values(values),
+ "INSERT INTO sometable (id, data, foo) VALUES "
+ "(%(id_0)s, %(data_0)s, %(foo)s), "
+ "(%(id_1)s, %(data_1)s, %(foo_1)s), "
+ "(%(id_2)s, %(data_2)s, %(foo_2)s)",
+ checkparams=checkparams,
+ dialect=postgresql.dialect())
+
def test_sql_functions(self):
metadata = MetaData()
table = Table('sometable', metadata,
@@ -684,24 +788,10 @@ class MultirowTest(_InsertTestBase, fixtures.TablesTest, AssertsCompiledSQL):
{'id': 3, 'data': 'data3', 'foo': 'otherfoo'},
]
- checkparams = {
- 'id_0': 1,
- 'id_1': 2,
- 'id_2': 3,
- 'data_0': 'data1',
- 'data_1': 'data2',
- 'data_2': 'data3',
- 'foo_0': 'plainfoo',
- 'foo_2': 'otherfoo',
- }
-
- # note the effect here is that the first set of params
- # takes effect for the rest of them, when one is absent
- self.assert_compile(
- table.insert().values(values),
- 'INSERT INTO sometable (id, data, foo) VALUES '
- '(%(id_0)s, %(data_0)s, %(foo_0)s), '
- '(%(id_1)s, %(data_1)s, %(foo_0)s), '
- '(%(id_2)s, %(data_2)s, %(foo_2)s)',
- checkparams=checkparams,
- dialect=postgresql.dialect())
+ assert_raises_message(
+ exc.CompileError,
+ "INSERT value for column sometable.foo is explicitly rendered "
+ "as a boundparameter in the VALUES clause; a Python-side value or "
+ "SQL expression is required",
+ table.insert().values(values).compile
+ )