Improve sql for items table

Now if item_id or unique_name change, that counts as a record
being deleted and a new one inserted.
If neither of that changed but any other field did, the old
field gets updated with the new value.
This commit is contained in:
King_DuckZ 2020-08-12 01:07:34 +01:00
parent 4dd78099f1
commit 1b5e1f4365
2 changed files with 12 additions and 6 deletions

1
.gitignore vendored
View file

@ -2,3 +2,4 @@
tags
compile_commands.json
links.txt
*.bin

View file

@ -176,10 +176,10 @@ void OriginsDB::update (const Items& items) {
db.exec(string_query_create_items("items"));
db.exec("CREATE UNIQUE INDEX IF NOT EXISTS items_item_id_idx ON items(item_id, removal_date)");
//see https://stackoverflow.com/questions/22699409/sqlite-null-and-unique
db.exec("CREATE UNIQUE INDEX IF NOT EXISTS items_item_id_constraint ON items(item_id, ifnull(removal_date, 0))");
db.exec("CREATE UNIQUE INDEX IF NOT EXISTS unique_active_item_constraint ON items(item_id, unique_name, ifnull(removal_date, 0))");
SQLite::Statement query(db,
"INSERT OR IGNORE INTO items_staging "
"INSERT INTO items_staging "
"(item_id, unique_name, name, type, subtype, npc_price, slots) "
"VALUES(?1, ?2, ?3, ?4, ?5, ?6, ?7)"
);
@ -200,13 +200,18 @@ void OriginsDB::update (const Items& items) {
db.exec(
"UPDATE items SET removal_date = CURRENT_TIMESTAMP WHERE "
"removal_date IS NULL AND item_id IN ("
"SELECT item_id FROM items WHERE removal_date IS NULL EXCEPT "
"SELECT item_id FROM items_staging"
"SELECT item_id FROM ("
"SELECT item_id, unique_name FROM items WHERE removal_date IS NULL EXCEPT "
"SELECT item_id, unique_name FROM items_staging"
")"
")"
);
db.exec(
"INSERT OR IGNORE INTO items (item_id, unique_name, name, type, subtype, npc_price, slots) "
"SELECT item_id, unique_name, name, type, subtype, npc_price, slots FROM items_staging"
"INSERT INTO items (item_id, unique_name, name, type, subtype, npc_price, slots) "
"SELECT item_id, unique_name, name, type, subtype, npc_price, slots FROM items_staging WHERE true "
"ON CONFLICT(item_id, unique_name, ifnull(removal_date, 0)) DO UPDATE SET "
"name=excluded.name, type=excluded.type, subtype=excluded.subtype, "
"npc_price=excluded.npc_price, slots=excluded.slots"
);
db.exec("DROP TABLE items_staging");