From 821adce90022b2809a5056babb4fd9c1ca555a39 Mon Sep 17 00:00:00 2001 From: Simon Gibbons Date: Mon, 6 Jan 2020 16:06:30 +0000 Subject: [PATCH 1/3] ENH: Support multi row inserts in to_sql when using the sqlite fallback Currently we do not support multi row inserts into sqlite databases when `to_sql` is passed `method="multi"` - despite the documentation suggesting that this is supported. Adding support for this is straightforward - it only needs us to implement a single method on the SQLiteTable class and so this PR does just that. --- doc/source/whatsnew/v1.0.0.rst | 1 + pandas/io/sql.py | 15 +++++++++++---- pandas/tests/io/test_sql.py | 4 ++++ 3 files changed, 16 insertions(+), 4 deletions(-) diff --git a/doc/source/whatsnew/v1.0.0.rst b/doc/source/whatsnew/v1.0.0.rst index ec6ad38bbc7cf..770501289a220 100755 --- a/doc/source/whatsnew/v1.0.0.rst +++ b/doc/source/whatsnew/v1.0.0.rst @@ -1094,6 +1094,7 @@ I/O - Bug in :func:`pandas.io.json.json_normalize` where a missing value in the location specified by `record_path` would raise a ``TypeError`` (:issue:`30148`) - :func:`read_excel` now accepts binary data (:issue:`15914`) - Bug in :meth:`read_csv` in which encoding handling was limited to just the string `utf-16` for the C engine (:issue:`24130`) +- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`) Plotting ^^^^^^^^ diff --git a/pandas/io/sql.py b/pandas/io/sql.py index 58fed0d18dd4a..d6cf0274bac70 100644 --- a/pandas/io/sql.py +++ b/pandas/io/sql.py @@ -1440,7 +1440,7 @@ def _execute_create(self): for stmt in self.table: conn.execute(stmt) - def insert_statement(self): + def insert_statement(self, *, num_rows): names = list(map(str, self.frame.columns)) wld = "?" # wildcard char escape = _get_valid_sqlite_name @@ -1451,15 +1451,22 @@ def insert_statement(self): bracketed_names = [escape(column) for column in names] col_names = ",".join(bracketed_names) - wildcards = ",".join([wld] * len(names)) + + row_wildcards = ",".join([wld] * len(names)) + wildcards = ",".join(f"({row_wildcards})" for _ in range(num_rows)) insert_statement = ( - f"INSERT INTO {escape(self.name)} ({col_names}) VALUES ({wildcards})" + f"INSERT INTO {escape(self.name)} ({col_names}) VALUES {wildcards}" ) return insert_statement def _execute_insert(self, conn, keys, data_iter): data_list = list(data_iter) - conn.executemany(self.insert_statement(), data_list) + conn.executemany(self.insert_statement(num_rows=1), data_list) + + def _execute_insert_multi(self, conn, keys, data_iter): + data_list = list(data_iter) + flattened_data = [x for row in data_list for x in row] + conn.execute(self.insert_statement(num_rows=len(data_list)), flattened_data) def _create_table_setup(self): """ diff --git a/pandas/tests/io/test_sql.py b/pandas/tests/io/test_sql.py index 45b3e839a08d1..0ad9f2c1e941f 100644 --- a/pandas/tests/io/test_sql.py +++ b/pandas/tests/io/test_sql.py @@ -2148,6 +2148,10 @@ def test_to_sql_replace(self): def test_to_sql_append(self): self._to_sql_append() + def test_to_sql_method_multi(self): + # GH 29921 + self._to_sql(method="multi") + def test_create_and_drop_table(self): temp_frame = DataFrame( {"one": [1.0, 2.0, 3.0, 4.0], "two": [4.0, 3.0, 2.0, 1.0]} From c11398f17142aad5efb4e1821e52f4b998ba14ed Mon Sep 17 00:00:00 2001 From: Simon Gibbons Date: Thu, 16 Jan 2020 20:58:05 +0000 Subject: [PATCH 2/3] Move whatsnew message to v1.1.0 --- doc/source/whatsnew/v1.0.0.rst | 1 - doc/source/whatsnew/v1.1.0.rst | 2 +- 2 files changed, 1 insertion(+), 2 deletions(-) diff --git a/doc/source/whatsnew/v1.0.0.rst b/doc/source/whatsnew/v1.0.0.rst index 770501289a220..ec6ad38bbc7cf 100755 --- a/doc/source/whatsnew/v1.0.0.rst +++ b/doc/source/whatsnew/v1.0.0.rst @@ -1094,7 +1094,6 @@ I/O - Bug in :func:`pandas.io.json.json_normalize` where a missing value in the location specified by `record_path` would raise a ``TypeError`` (:issue:`30148`) - :func:`read_excel` now accepts binary data (:issue:`15914`) - Bug in :meth:`read_csv` in which encoding handling was limited to just the string `utf-16` for the C engine (:issue:`24130`) -- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`) Plotting ^^^^^^^^ diff --git a/doc/source/whatsnew/v1.1.0.rst b/doc/source/whatsnew/v1.1.0.rst index 8cbc95f0349cf..a47b185633ffb 100644 --- a/doc/source/whatsnew/v1.1.0.rst +++ b/doc/source/whatsnew/v1.1.0.rst @@ -132,7 +132,7 @@ MultiIndex I/O ^^^ - +- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`) - - From c22812816240b2f32dbf0ba4ff7c252737f1ed0a Mon Sep 17 00:00:00 2001 From: Simon Gibbons Date: Tue, 21 Jan 2020 10:53:50 +0000 Subject: [PATCH 3/3] Move around whatsnew --- doc/source/whatsnew/v1.1.0.rst | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/doc/source/whatsnew/v1.1.0.rst b/doc/source/whatsnew/v1.1.0.rst index a47b185633ffb..4c14f9735157b 100644 --- a/doc/source/whatsnew/v1.1.0.rst +++ b/doc/source/whatsnew/v1.1.0.rst @@ -19,6 +19,7 @@ Other enhancements ^^^^^^^^^^^^^^^^^^ - :class:`Styler` may now render CSS more efficiently where multiple cells have the same styling (:issue:`30876`) +- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`) - - @@ -132,7 +133,7 @@ MultiIndex I/O ^^^ -- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`) + - -