Commits

idank committed ac0404d

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.

  • Participants
  • Parent commits c3efee6

Comments (0)

Files changed (7)

lib/sqlalchemy/dialects/mysql/base.py

 
     supports_sane_rowcount = True
     supports_sane_multi_rowcount = False
+    supports_multirow_insert = True
 
     default_paramstyle = 'format'
     colspecs = colspecs

lib/sqlalchemy/dialects/postgresql/base.py

 
     supports_default_values = True
     supports_empty_insert = False
+    supports_multirow_insert = True
     default_paramstyle = 'pyformat'
     ischema_names = ischema_names
     colspecs = colspecs

lib/sqlalchemy/dialects/sqlite/base.py

     supports_default_values = True
     supports_empty_insert = False
     supports_cast = True
+    supports_multirow_insert = True
 
     default_paramstyle = 'qmark'
     execution_ctx_cls = SQLiteExecutionContext

lib/sqlalchemy/engine/default.py

     default_paramstyle = 'named'
     supports_default_values = False
     supports_empty_insert = True
+    supports_multirow_insert = False
 
     server_version_info = None
 

lib/sqlalchemy/sql/compiler.py

                                     "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
 
         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
 
         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
         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):

test/sql/test_compiler.py

                     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),

test/sql/test_query.py

     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."""