Skip to content

Commit 9421d9f

Browse files
committed
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.
1 parent 6600b5b commit 9421d9f

File tree

3 files changed

+16
-4
lines changed

3 files changed

+16
-4
lines changed

doc/source/whatsnew/v1.0.0.rst

+1
Original file line numberDiff line numberDiff line change
@@ -946,6 +946,7 @@ I/O
946946
- 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`)
947947
- :func:`read_excel` now accepts binary data (:issue:`15914`)
948948
- Bug in :meth:`read_csv` in which encoding handling was limited to just the string `utf-16` for the C engine (:issue:`24130`)
949+
- When writing directly to a sqlite connection :func:`to_sql` now supports the ``multi`` method (:issue:`29921`)
949950

950951
Plotting
951952
^^^^^^^^

pandas/io/sql.py

+11-4
Original file line numberDiff line numberDiff line change
@@ -1442,7 +1442,7 @@ def _execute_create(self):
14421442
for stmt in self.table:
14431443
conn.execute(stmt)
14441444

1445-
def insert_statement(self):
1445+
def insert_statement(self, *, num_rows):
14461446
names = list(map(str, self.frame.columns))
14471447
wld = "?" # wildcard char
14481448
escape = _get_valid_sqlite_name
@@ -1453,15 +1453,22 @@ def insert_statement(self):
14531453

14541454
bracketed_names = [escape(column) for column in names]
14551455
col_names = ",".join(bracketed_names)
1456-
wildcards = ",".join([wld] * len(names))
1456+
1457+
row_wildcards = ",".join([wld] * len(names))
1458+
wildcards = ",".join(f"({row_wildcards})" for _ in range(num_rows))
14571459
insert_statement = (
1458-
f"INSERT INTO {escape(self.name)} ({col_names}) VALUES ({wildcards})"
1460+
f"INSERT INTO {escape(self.name)} ({col_names}) VALUES {wildcards}"
14591461
)
14601462
return insert_statement
14611463

14621464
def _execute_insert(self, conn, keys, data_iter):
14631465
data_list = list(data_iter)
1464-
conn.executemany(self.insert_statement(), data_list)
1466+
conn.executemany(self.insert_statement(num_rows=1), data_list)
1467+
1468+
def _execute_insert_multi(self, conn, keys, data_iter):
1469+
data_list = list(data_iter)
1470+
flattened_data = [x for row in data_list for x in row]
1471+
conn.execute(self.insert_statement(num_rows=len(data_list)), flattened_data)
14651472

14661473
def _create_table_setup(self):
14671474
"""

pandas/tests/io/test_sql.py

+4
Original file line numberDiff line numberDiff line change
@@ -2148,6 +2148,10 @@ def test_to_sql_replace(self):
21482148
def test_to_sql_append(self):
21492149
self._to_sql_append()
21502150

2151+
def test_to_sql_method_multi(self):
2152+
# GH 29921
2153+
self._to_sql(method="multi")
2154+
21512155
def test_create_and_drop_table(self):
21522156
temp_frame = DataFrame(
21532157
{"one": [1.0, 2.0, 3.0, 4.0], "two": [4.0, 3.0, 2.0, 1.0]}

0 commit comments

Comments
 (0)