1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634
|
"""SQLite-specific tests."""
from sqlalchemy import Column
from sqlalchemy import exc
from sqlalchemy import schema
from sqlalchemy import sql
from sqlalchemy import Table
from sqlalchemy import testing
from sqlalchemy import types as sqltypes
from sqlalchemy.dialects.sqlite import insert
from sqlalchemy.testing import assert_raises
from sqlalchemy.testing import eq_
from sqlalchemy.testing import expect_raises
from sqlalchemy.testing import fixtures
from sqlalchemy.types import Integer
from sqlalchemy.types import String
class OnConflictTest(fixtures.TablesTest):
__only_on__ = ("sqlite >= 3.24.0",)
__backend__ = True
@classmethod
def define_tables(cls, metadata):
Table(
"users",
metadata,
Column("id", Integer, primary_key=True),
Column("name", String(50)),
)
Table(
"users_w_key",
metadata,
Column("id", Integer, primary_key=True),
Column("name", String(50), key="name_keyed"),
)
class SpecialType(sqltypes.TypeDecorator):
impl = String
cache_ok = True
def process_bind_param(self, value, dialect):
return value + " processed"
Table(
"bind_targets",
metadata,
Column("id", Integer, primary_key=True),
Column("data", SpecialType()),
)
users_xtra = Table(
"users_xtra",
metadata,
Column("id", Integer, primary_key=True),
Column("name", String(50)),
Column("login_email", String(50)),
Column("lets_index_this", String(50)),
)
cls.unique_partial_index = schema.Index(
"idx_unique_partial_name",
users_xtra.c.name,
users_xtra.c.lets_index_this,
unique=True,
sqlite_where=users_xtra.c.lets_index_this == "unique_name",
)
cls.unique_constraint = schema.UniqueConstraint(
users_xtra.c.login_email, name="uq_login_email"
)
cls.bogus_index = schema.Index(
"idx_special_ops",
users_xtra.c.lets_index_this,
sqlite_where=users_xtra.c.lets_index_this > "m",
)
def test_bad_args(self):
with expect_raises(ValueError):
insert(self.tables.users).on_conflict_do_update()
def test_on_conflict_do_no_call_twice(self):
users = self.tables.users
for stmt in (
insert(users).on_conflict_do_nothing(),
insert(users).on_conflict_do_update(
index_elements=[users.c.id], set_=dict(name="foo")
),
):
for meth in (
stmt.on_conflict_do_nothing,
stmt.on_conflict_do_update,
):
with testing.expect_raises_message(
exc.InvalidRequestError,
"This Insert construct already has an "
"ON CONFLICT clause established",
):
meth()
def test_on_conflict_do_nothing(self, connection):
users = self.tables.users
conn = connection
result = conn.execute(
insert(users).on_conflict_do_nothing(),
dict(id=1, name="name1"),
)
eq_(result.inserted_primary_key, (1,))
result = conn.execute(
insert(users).on_conflict_do_nothing(),
dict(id=1, name="name2"),
)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name1")],
)
def test_on_conflict_do_nothing_connectionless(self, connection):
users = self.tables.users_xtra
result = connection.execute(
insert(users).on_conflict_do_nothing(
index_elements=["login_email"]
),
dict(name="name1", login_email="email1"),
)
eq_(result.inserted_primary_key, (1,))
result = connection.execute(
insert(users).on_conflict_do_nothing(
index_elements=["login_email"]
),
dict(name="name2", login_email="email1"),
)
eq_(result.inserted_primary_key, (1,))
eq_(
connection.execute(
users.select().where(users.c.id == 1)
).fetchall(),
[(1, "name1", "email1", None)],
)
@testing.provide_metadata
def test_on_conflict_do_nothing_target(self, connection):
users = self.tables.users
conn = connection
result = conn.execute(
insert(users).on_conflict_do_nothing(
index_elements=users.primary_key.columns
),
dict(id=1, name="name1"),
)
eq_(result.inserted_primary_key, (1,))
result = conn.execute(
insert(users).on_conflict_do_nothing(
index_elements=users.primary_key.columns
),
dict(id=1, name="name2"),
)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name1")],
)
@testing.combinations(
("with_dict", True),
("issue_5939", False),
id_="ia",
argnames="with_dict",
)
def test_on_conflict_do_update_one(self, connection, with_dict):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=[users.c.id],
set_=dict(name=i.excluded.name) if with_dict else i.excluded,
)
result = conn.execute(i, dict(id=1, name="name1"))
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name1")],
)
def test_on_conflict_do_update_two(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=[users.c.id],
set_=dict(id=i.excluded.id, name=i.excluded.name),
)
result = conn.execute(i, dict(id=1, name="name2"))
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name2")],
)
def test_on_conflict_do_update_three(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_=dict(name=i.excluded.name),
)
result = conn.execute(i, dict(id=1, name="name3"))
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name3")],
)
def test_on_conflict_do_update_four(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_=dict(id=i.excluded.id, name=i.excluded.name),
).values(id=1, name="name4")
result = conn.execute(i)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name4")],
)
def test_on_conflict_do_update_five(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_=dict(id=10, name="I'm a name"),
).values(id=1, name="name4")
result = conn.execute(i)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 10)).fetchall(),
[(10, "I'm a name")],
)
def test_on_conflict_do_update_column_keys(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_={users.c.id: 10, users.c.name: "I'm a name"},
).values(id=1, name="name4")
result = conn.execute(i)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 10)).fetchall(),
[(10, "I'm a name")],
)
def test_on_conflict_do_update_clauseelem_keys(self, connection):
users = self.tables.users
class MyElem:
def __init__(self, expr):
self.expr = expr
def __clause_element__(self):
return self.expr
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_={MyElem(users.c.id): 10, MyElem(users.c.name): "I'm a name"},
).values({MyElem(users.c.id): 1, MyElem(users.c.name): "name4"})
result = conn.execute(i)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 10)).fetchall(),
[(10, "I'm a name")],
)
def test_on_conflict_do_update_multivalues(self, connection):
users = self.tables.users
conn = connection
conn.execute(users.insert(), dict(id=1, name="name1"))
conn.execute(users.insert(), dict(id=2, name="name2"))
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_=dict(name="updated"),
where=(i.excluded.name != "name12"),
).values(
[
dict(id=1, name="name11"),
dict(id=2, name="name12"),
dict(id=3, name="name13"),
dict(id=4, name="name14"),
]
)
result = conn.execute(i)
eq_(result.inserted_primary_key, (None,))
eq_(
conn.execute(users.select().order_by(users.c.id)).fetchall(),
[(1, "updated"), (2, "name2"), (3, "name13"), (4, "name14")],
)
def _exotic_targets_fixture(self, conn):
users = self.tables.users_xtra
conn.execute(
insert(users),
dict(
id=1,
name="name1",
login_email="name1@gmail.com",
lets_index_this="not",
),
)
conn.execute(
users.insert(),
dict(
id=2,
name="name2",
login_email="name2@gmail.com",
lets_index_this="not",
),
)
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name1", "name1@gmail.com", "not")],
)
def test_on_conflict_do_update_exotic_targets_two(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
# try primary key constraint: cause an upsert on unique id column
i = insert(users)
i = i.on_conflict_do_update(
index_elements=users.primary_key.columns,
set_=dict(
name=i.excluded.name, login_email=i.excluded.login_email
),
)
result = conn.execute(
i,
dict(
id=1,
name="name2",
login_email="name1@gmail.com",
lets_index_this="not",
),
)
eq_(result.inserted_primary_key, (1,))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[(1, "name2", "name1@gmail.com", "not")],
)
def test_on_conflict_do_update_exotic_targets_three(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
# try unique constraint: cause an upsert on target
# login_email, not id
i = insert(users)
i = i.on_conflict_do_update(
index_elements=["login_email"],
set_=dict(
id=i.excluded.id,
name=i.excluded.name,
login_email=i.excluded.login_email,
),
)
# note: lets_index_this value totally ignored in SET clause.
result = conn.execute(
i,
dict(
id=42,
name="nameunique",
login_email="name2@gmail.com",
lets_index_this="unique",
),
)
eq_(result.inserted_primary_key, (42,))
eq_(
conn.execute(
users.select().where(users.c.login_email == "name2@gmail.com")
).fetchall(),
[(42, "nameunique", "name2@gmail.com", "not")],
)
def test_on_conflict_do_update_exotic_targets_four(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
# try unique constraint by name: cause an
# upsert on target login_email, not id
i = insert(users)
i = i.on_conflict_do_update(
index_elements=["login_email"],
set_=dict(
id=i.excluded.id,
name=i.excluded.name,
login_email=i.excluded.login_email,
),
)
# note: lets_index_this value totally ignored in SET clause.
result = conn.execute(
i,
dict(
id=43,
name="nameunique2",
login_email="name2@gmail.com",
lets_index_this="unique",
),
)
eq_(result.inserted_primary_key, (43,))
eq_(
conn.execute(
users.select().where(users.c.login_email == "name2@gmail.com")
).fetchall(),
[(43, "nameunique2", "name2@gmail.com", "not")],
)
def test_on_conflict_do_update_exotic_targets_four_no_pk(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
# try unique constraint by name: cause an
# upsert on target login_email, not id
i = insert(users)
i = i.on_conflict_do_update(
index_elements=[users.c.login_email],
set_=dict(
id=i.excluded.id,
name=i.excluded.name,
login_email=i.excluded.login_email,
),
)
conn.execute(i, dict(name="name3", login_email="name1@gmail.com"))
eq_(
conn.execute(users.select().where(users.c.id == 1)).fetchall(),
[],
)
eq_(
conn.execute(users.select().order_by(users.c.id)).fetchall(),
[
(2, "name2", "name2@gmail.com", "not"),
(3, "name3", "name1@gmail.com", "not"),
],
)
def test_on_conflict_do_update_exotic_targets_five(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
# try bogus index
i = insert(users)
i = i.on_conflict_do_update(
index_elements=self.bogus_index.columns,
index_where=self.bogus_index.dialect_options["sqlite"]["where"],
set_=dict(
name=i.excluded.name, login_email=i.excluded.login_email
),
)
assert_raises(
exc.OperationalError,
conn.execute,
i,
dict(
id=1,
name="namebogus",
login_email="bogus@gmail.com",
lets_index_this="bogus",
),
)
def test_on_conflict_do_update_exotic_targets_six(self, connection):
users = self.tables.users_xtra
conn = connection
conn.execute(
insert(users),
dict(
id=1,
name="name1",
login_email="mail1@gmail.com",
lets_index_this="unique_name",
),
)
i = insert(users)
i = i.on_conflict_do_update(
index_elements=self.unique_partial_index.columns,
index_where=self.unique_partial_index.dialect_options["sqlite"][
"where"
],
set_=dict(
name=i.excluded.name, login_email=i.excluded.login_email
),
)
conn.execute(
i,
[
dict(
name="name1",
login_email="mail2@gmail.com",
lets_index_this="unique_name",
)
],
)
eq_(
conn.execute(users.select()).fetchall(),
[(1, "name1", "mail2@gmail.com", "unique_name")],
)
def test_on_conflict_do_update_no_row_actually_affected(self, connection):
users = self.tables.users_xtra
conn = connection
self._exotic_targets_fixture(conn)
i = insert(users)
i = i.on_conflict_do_update(
index_elements=[users.c.login_email],
set_=dict(name="new_name"),
where=(i.excluded.name == "other_name"),
)
result = conn.execute(
i, dict(name="name2", login_email="name1@gmail.com")
)
# The last inserted primary key should be 2 here
# it is taking the result from the exotic fixture
eq_(result.inserted_primary_key, (2,))
eq_(
conn.execute(users.select()).fetchall(),
[
(1, "name1", "name1@gmail.com", "not"),
(2, "name2", "name2@gmail.com", "not"),
],
)
def test_on_conflict_do_update_special_types_in_set(self, connection):
bind_targets = self.tables.bind_targets
conn = connection
i = insert(bind_targets)
conn.execute(i, {"id": 1, "data": "initial data"})
eq_(
conn.scalar(sql.select(bind_targets.c.data)),
"initial data processed",
)
i = insert(bind_targets)
i = i.on_conflict_do_update(
index_elements=[bind_targets.c.id],
set_=dict(data="new updated data"),
)
conn.execute(i, {"id": 1, "data": "new inserted data"})
eq_(
conn.scalar(sql.select(bind_targets.c.data)),
"new updated data processed",
)
|