From: Idan Kamara Date: Wed, 5 Dec 2012 22:11:52 +0000 (+0200) Subject: compiler: add support for multirow inserts X-Git-Tag: rel_0_8_0b2~18 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=d57c1c2ddd654a1077ab04ba7277828d9030c23d;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git compiler: add support for multirow inserts Some databases support this syntax for inserts: INSERT INTO table (id, name) VALUES ('v1', 'v2'), ('v3', 'v4'); which greatly increases INSERT speed. It is now possible to pass a list of lists/tuples/dictionaries as the values param to the Insert construct. We convert it to a flat dictionary so we can continue using bind params. The above query will be converted to: INSERT INTO table (id, name) VALUES (:id, :name), (:id0, :name0); Currently only supported on postgresql, mysql and sqlite. --- diff --git a/lib/sqlalchemy/dialects/mysql/base.py b/lib/sqlalchemy/dialects/mysql/base.py index 2cda1a1474..5f515c936c 100644 --- a/lib/sqlalchemy/dialects/mysql/base.py +++ b/lib/sqlalchemy/dialects/mysql/base.py @@ -1882,6 +1882,7 @@ class MySQLDialect(default.DefaultDialect): supports_sane_rowcount = True supports_sane_multi_rowcount = False + supports_multirow_insert = True default_paramstyle = 'format' colspecs = colspecs diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index ed24bc1fe0..22667b3176 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -1182,6 +1182,7 @@ class PGDialect(default.DefaultDialect): supports_default_values = True supports_empty_insert = False + supports_multirow_insert = True default_paramstyle = 'pyformat' ischema_names = ischema_names colspecs = colspecs diff --git a/lib/sqlalchemy/dialects/sqlite/base.py b/lib/sqlalchemy/dialects/sqlite/base.py index 6d2d0e89d1..d1532b9bb1 100644 --- a/lib/sqlalchemy/dialects/sqlite/base.py +++ b/lib/sqlalchemy/dialects/sqlite/base.py @@ -601,6 +601,7 @@ class SQLiteDialect(default.DefaultDialect): supports_default_values = True supports_empty_insert = False supports_cast = True + supports_multirow_insert = True default_paramstyle = 'qmark' execution_ctx_cls = SQLiteExecutionContext diff --git a/lib/sqlalchemy/engine/default.py b/lib/sqlalchemy/engine/default.py index e0068dde14..7de0dcee7b 100644 --- a/lib/sqlalchemy/engine/default.py +++ b/lib/sqlalchemy/engine/default.py @@ -85,6 +85,7 @@ class DefaultDialect(interfaces.Dialect): default_paramstyle = 'named' supports_default_values = False supports_empty_insert = True + supports_multirow_insert = False server_version_info = None diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index 6f7f1dadd2..3856499fcc 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -1284,6 +1284,11 @@ class SQLCompiler(engine.Compiled): "not support empty inserts." % self.dialect.name) + if insert_stmt.multi_parameters and not self.dialect.supports_multirow_insert: + raise exc.CompileError("The version of %s you are using does " + "not support multirow inserts." % + self.dialect.name) + preparer = self.preparer supports_default_values = self.dialect.supports_default_values @@ -1328,8 +1333,11 @@ class SQLCompiler(engine.Compiled): if not cols and supports_default_values: text += " DEFAULT VALUES" else: - text += " VALUES (%s)" % \ - ', '.join(params[0]) + values = [] + for row in params: + values.append('(%s)' % ', '.join(row)) + text += " VALUES %s" % \ + ', '.join(values) if self.returning and not self.returning_precedes_values: text += " " + returning_clause @@ -1445,8 +1453,10 @@ class SQLCompiler(engine.Compiled): return text - def _create_crud_bind_param(self, col, value, required=False): - bindparam = sql.bindparam(col.key, value, + def _create_crud_bind_param(self, col, value, required=False, name=None): + if name is None: + name = col.key + bindparam = sql.bindparam(name, value, type_=col.type, required=required, quote=col.quote) bindparam._is_crud = True @@ -1669,6 +1679,13 @@ class SQLCompiler(engine.Compiled): if values: values = [values] + for i, row in enumerate(stmt.multi_parameters): + r = [] + for c in columns: + r.append(self._create_crud_bind_param(c, row[c.key], + name=c.key + str(i))) + values.append(r) + return columns, values def visit_delete(self, delete_stmt, **kw): diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index 50b425a019..3b0e421ae7 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -2552,6 +2552,21 @@ class CRUDTest(fixtures.TestBase, AssertsCompiledSQL): table.insert(inline=True), "INSERT INTO sometable (foo) VALUES (foobar())", params={}) + def test_multirow_insert(self): + data = [(1, 'a', 'b'), (2, 'a', 'b')] + result = "INSERT INTO mytable (myid, name, description) VALUES " \ + "(%(myid)s, %(name)s, %(description)s), " \ + "(%(myid0)s, %(name0)s, %(description0)s)" + + stmt = insert(table1, data, dialect='postgresql') + self.assert_compile(stmt, result, dialect=postgresql.dialect()) + + stmt = table1.insert(values=data, dialect='postgresql') + self.assert_compile(stmt, result, dialect=postgresql.dialect()) + + stmt = table1.insert(dialect='postgresql').values(data) + self.assert_compile(stmt, result, dialect=postgresql.dialect()) + def test_update(self): self.assert_compile( update(table1, table1.c.myid == 7), diff --git a/test/sql/test_query.py b/test/sql/test_query.py index 95e1593161..9da9c2ff9d 100644 --- a/test/sql/test_query.py +++ b/test/sql/test_query.py @@ -48,6 +48,17 @@ class QueryTest(fixtures.TestBase): def teardown_class(cls): metadata.drop_all() + def test_multirow_insert(self): + users.insert(values=[{'user_id':7, 'user_name':'jack'}, + {'user_id':8, 'user_name':'ed'}]).execute() + rows = users.select().execute().fetchall() + self.assert_(rows[0] == (7, 'jack')) + self.assert_(rows[1] == (8, 'ed')) + users.insert(values=[(9, 'jack'), (10, 'ed')]).execute() + rows = users.select().execute().fetchall() + self.assert_(rows[2] == (9, 'jack')) + self.assert_(rows[3] == (10, 'ed')) + def test_insert_heterogeneous_params(self): """test that executemany parameters are asserted to match the parameter set of the first."""