Skip to content

Commit 947d14f

Browse files
authored
DOC: Add to_sql example of conflict with method parameter (#53264)
* DOC: Add to_sql example of conflict do nothing * Use fixture to skip * Add example of conflict update
1 parent 5f4dcdf commit 947d14f

File tree

2 files changed

+141
-0
lines changed

2 files changed

+141
-0
lines changed

pandas/core/generic.py

+30
Original file line numberDiff line numberDiff line change
@@ -2900,6 +2900,36 @@ def to_sql(
29002900
... conn.execute(text("SELECT * FROM users")).fetchall()
29012901
[(0, 'User 6'), (1, 'User 7')]
29022902
2903+
Use ``method`` to define a callable insertion method to do nothing
2904+
if there's a primary key conflict on a table in a PostgreSQL database.
2905+
2906+
>>> from sqlalchemy.dialects.postgresql import insert
2907+
>>> def insert_on_conflict_nothing(table, conn, keys, data_iter):
2908+
... # "a" is the primary key in "conflict_table"
2909+
... data = [dict(zip(keys, row)) for row in data_iter]
2910+
... stmt = insert(table.table).values(data).on_conflict_do_nothing(index_elements=["a"])
2911+
... result = conn.execute(stmt)
2912+
... return result.rowcount
2913+
>>> df_conflict.to_sql("conflict_table", conn, if_exists="append", method=insert_on_conflict_nothing) # doctest: +SKIP
2914+
0
2915+
2916+
For MySQL, a callable to update columns ``b`` and ``c`` if there's a conflict
2917+
on a primary key.
2918+
2919+
>>> from sqlalchemy.dialects.mysql import insert
2920+
>>> def insert_on_conflict_update(table, conn, keys, data_iter):
2921+
... # update columns "b" and "c" on primary key conflict
2922+
... data = [dict(zip(keys, row)) for row in data_iter]
2923+
... stmt = (
2924+
... insert(table.table)
2925+
... .values(data)
2926+
... )
2927+
... stmt = stmt.on_duplicate_key_update(b=stmt.inserted.b, c=stmt.inserted.c)
2928+
... result = conn.execute(stmt)
2929+
... return result.rowcount
2930+
>>> df_conflict.to_sql("conflict_table", conn, if_exists="append", method=insert_on_conflict_update) # doctest: +SKIP
2931+
2
2932+
29032933
Specify the dtype (especially useful for integers with missing values).
29042934
Notice that while pandas is forced to store the data as floating point,
29052935
the database supports nullable integers. When fetching the data with

pandas/tests/io/test_sql.py

+111
Original file line numberDiff line numberDiff line change
@@ -820,6 +820,117 @@ def psql_insert_copy(table, conn, keys, data_iter):
820820
tm.assert_frame_equal(result, expected)
821821

822822

823+
@pytest.mark.db
824+
@pytest.mark.parametrize("conn", postgresql_connectable)
825+
def test_insertion_method_on_conflict_do_nothing(conn, request):
826+
# GH 15988: Example in to_sql docstring
827+
conn = request.getfixturevalue(conn)
828+
829+
from sqlalchemy.dialects.postgresql import insert
830+
from sqlalchemy.engine import Engine
831+
from sqlalchemy.sql import text
832+
833+
def insert_on_conflict(table, conn, keys, data_iter):
834+
data = [dict(zip(keys, row)) for row in data_iter]
835+
stmt = (
836+
insert(table.table)
837+
.values(data)
838+
.on_conflict_do_nothing(index_elements=["a"])
839+
)
840+
result = conn.execute(stmt)
841+
return result.rowcount
842+
843+
create_sql = text(
844+
"""
845+
CREATE TABLE test_insert_conflict (
846+
a integer PRIMARY KEY,
847+
b numeric,
848+
c text
849+
);
850+
"""
851+
)
852+
if isinstance(conn, Engine):
853+
with conn.connect() as con:
854+
with con.begin():
855+
con.execute(create_sql)
856+
else:
857+
with conn.begin():
858+
conn.execute(create_sql)
859+
860+
expected = DataFrame([[1, 2.1, "a"]], columns=list("abc"))
861+
expected.to_sql("test_insert_conflict", conn, if_exists="append", index=False)
862+
863+
df_insert = DataFrame([[1, 3.2, "b"]], columns=list("abc"))
864+
inserted = df_insert.to_sql(
865+
"test_insert_conflict",
866+
conn,
867+
index=False,
868+
if_exists="append",
869+
method=insert_on_conflict,
870+
)
871+
result = sql.read_sql_table("test_insert_conflict", conn)
872+
tm.assert_frame_equal(result, expected)
873+
assert inserted == 0
874+
875+
# Cleanup
876+
with sql.SQLDatabase(conn, need_transaction=True) as pandasSQL:
877+
pandasSQL.drop_table("test_insert_conflict")
878+
879+
880+
@pytest.mark.db
881+
@pytest.mark.parametrize("conn", mysql_connectable)
882+
def test_insertion_method_on_conflict_update(conn, request):
883+
# GH 14553: Example in to_sql docstring
884+
conn = request.getfixturevalue(conn)
885+
886+
from sqlalchemy.dialects.mysql import insert
887+
from sqlalchemy.engine import Engine
888+
from sqlalchemy.sql import text
889+
890+
def insert_on_conflict(table, conn, keys, data_iter):
891+
data = [dict(zip(keys, row)) for row in data_iter]
892+
stmt = insert(table.table).values(data)
893+
stmt = stmt.on_duplicate_key_update(b=stmt.inserted.b, c=stmt.inserted.c)
894+
result = conn.execute(stmt)
895+
return result.rowcount
896+
897+
create_sql = text(
898+
"""
899+
CREATE TABLE test_insert_conflict (
900+
a INT PRIMARY KEY,
901+
b FLOAT,
902+
c VARCHAR(10)
903+
);
904+
"""
905+
)
906+
if isinstance(conn, Engine):
907+
with conn.connect() as con:
908+
with con.begin():
909+
con.execute(create_sql)
910+
else:
911+
with conn.begin():
912+
conn.execute(create_sql)
913+
914+
df = DataFrame([[1, 2.1, "a"]], columns=list("abc"))
915+
df.to_sql("test_insert_conflict", conn, if_exists="append", index=False)
916+
917+
expected = DataFrame([[1, 3.2, "b"]], columns=list("abc"))
918+
inserted = expected.to_sql(
919+
"test_insert_conflict",
920+
conn,
921+
index=False,
922+
if_exists="append",
923+
method=insert_on_conflict,
924+
)
925+
result = sql.read_sql_table("test_insert_conflict", conn)
926+
tm.assert_frame_equal(result, expected)
927+
assert inserted == 2
928+
929+
# Cleanup
930+
with sql.SQLDatabase(conn, need_transaction=True) as pandasSQL:
931+
pandasSQL.drop_table("test_insert_conflict")
932+
933+
823934
def test_execute_typeerror(sqlite_iris_engine):
824935
with pytest.raises(TypeError, match="pandas.io.sql.execute requires a connection"):
825936
with tm.assert_produces_warning(

0 commit comments

Comments
 (0)