Skip to content

Commit

Permalink
.transform() now preserves rowid values, refs #592
Browse files Browse the repository at this point in the history
  • Loading branch information
simonw committed Sep 8, 2023
1 parent 5d123f0 commit 4914eb1
Show file tree
Hide file tree
Showing 2 changed files with 41 additions and 13 deletions.
4 changes: 4 additions & 0 deletions sqlite_utils/db.py
Original file line number Diff line number Diff line change
Expand Up @@ -1917,6 +1917,10 @@ def transform_sql(
for from_, to_ in copy_from_to.items():
old_cols.append(from_)
new_cols.append(to_)
# Ensure rowid is copied too
if "rowid" not in new_cols:
new_cols.insert(0, "rowid")
old_cols.insert(0, "rowid")
copy_sql = "INSERT INTO [{new_table}] ({new_cols})\n SELECT {old_cols} FROM [{old_table}];".format(
new_table=new_table_name,
old_table=self.name,
Expand Down
50 changes: 37 additions & 13 deletions tests/test_transform.py
Original file line number Diff line number Diff line change
Expand Up @@ -11,7 +11,7 @@
{},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -21,7 +21,7 @@
{"types": {"age": int}},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [age] INTEGER\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -31,7 +31,7 @@
{"rename": {"age": "dog_age"}},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [dog_age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [dog_age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [dog_age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -41,7 +41,7 @@
{"drop": ["age"]},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name])\n SELECT [id], [name] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name])\n SELECT [rowid], [id], [name] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -51,7 +51,7 @@
{"types": {"age": int}, "rename": {"age": "dog_age"}},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [dog_age] INTEGER\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [dog_age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [dog_age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -61,7 +61,7 @@
{"pk": "age"},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [age] TEXT PRIMARY KEY\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -71,7 +71,7 @@
{"pk": ("age", "name")},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [age] TEXT,\n PRIMARY KEY ([age], [name])\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -81,7 +81,7 @@
{"pk": None},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -91,7 +91,7 @@
{"drop": ["age"], "keep_table": "kept_table"},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name])\n SELECT [id], [name] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name])\n SELECT [rowid], [id], [name] FROM [dogs];",
"ALTER TABLE [dogs] RENAME TO [kept_table];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand Down Expand Up @@ -134,7 +134,7 @@ def tracer(sql, params):
{},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -144,7 +144,7 @@ def tracer(sql, params):
{"types": {"age": int}},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [age] INTEGER\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -154,7 +154,7 @@ def tracer(sql, params):
{"rename": {"age": "dog_age"}},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER,\n [name] TEXT,\n [dog_age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [dog_age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [dog_age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand All @@ -164,7 +164,7 @@ def tracer(sql, params):
{"pk": "id"},
[
"CREATE TABLE [dogs_new_suffix] (\n [id] INTEGER PRIMARY KEY,\n [name] TEXT,\n [age] TEXT\n);",
"INSERT INTO [dogs_new_suffix] ([id], [name], [age])\n SELECT [id], [name], [age] FROM [dogs];",
"INSERT INTO [dogs_new_suffix] ([rowid], [id], [name], [age])\n SELECT [rowid], [id], [name], [age] FROM [dogs];",
"DROP TABLE [dogs];",
"ALTER TABLE [dogs_new_suffix] RENAME TO [dogs];",
],
Expand Down Expand Up @@ -498,3 +498,27 @@ def test_transform_replace_foreign_keys(fresh_db, foreign_keys):
" [city] INTEGER\n"
")"
)


def test_transform_preserves_rowids(fresh_db):
fresh_db["places"].insert_all(
[
{"id": "1", "name": "Paris", "country": "France"},
{"id": "2", "name": "London", "country": "UK"},
{"id": "3", "name": "New York", "country": "USA"},
],
pk="id",
)
# Now delete and insert a row to mix up the `rowid` sequence
fresh_db["places"].delete_where("id = ?", ["2"])
fresh_db["places"].insert({"id": "4", "name": "London", "country": "UK"})
previous_rows = list(
tuple(row) for row in fresh_db.execute("select rowid, id, name from places")
)
# Transform it
fresh_db["places"].transform(column_order=("country", "name"))
# Should be the same
next_rows = list(
tuple(row) for row in fresh_db.execute("select rowid, id, name from places")
)
assert previous_rows == next_rows

0 comments on commit 4914eb1

Please sign in to comment.