Fix issue with items table; enable foreign key constraints
Program receives the full items list periodically. I don't think they will ever remove records from there, but if they do the program should not corruct the db. So far the simple approach drop table items/create table items ensured the items list is always fresh, but it prevented foreign key constraints on shop items. Also, if an item was removed from items, any entry in shop would become orphaned or worse point to the wrong item if they recycled the id. Solution is to not use item_id at all for the relationship between shop items and items table, instead have my own internal id that is valid forever. Now records removed upstream get just marked as deleted (by adding a removal timestamp). The same item_id can be reused since the unique part now must be (item_id, removal_date), in other words there is only one non-deleted item_id, but there can be several deleted ones. Code stores the full items set into items_staging, marks records in items but not in items_staging as deleted, then adds any missing records to items from items_staging, then drops items_staging.
This commit is contained in:
parent
cb500fd67c
commit
ef39dee43e
1 changed files with 89 additions and 22 deletions
|
@ -28,6 +28,8 @@
|
||||||
#include <mutex>
|
#include <mutex>
|
||||||
#include <optional>
|
#include <optional>
|
||||||
#include <type_traits>
|
#include <type_traits>
|
||||||
|
#include <unordered_map>
|
||||||
|
#include <cstdint>
|
||||||
|
|
||||||
namespace oro {
|
namespace oro {
|
||||||
|
|
||||||
|
@ -42,6 +44,39 @@ namespace {
|
||||||
}
|
}
|
||||||
};
|
};
|
||||||
|
|
||||||
|
class ItemIdToTableId {
|
||||||
|
public:
|
||||||
|
explicit ItemIdToTableId (SQLite::Database& db) :
|
||||||
|
m_db(db),
|
||||||
|
m_query(m_db, "SELECT id FROM items WHERE item_id = ? AND removal_date IS NULL")
|
||||||
|
{
|
||||||
|
}
|
||||||
|
|
||||||
|
int64_t operator() (int item_id) {
|
||||||
|
{
|
||||||
|
auto it_found = m_cache.find(item_id);
|
||||||
|
if (m_cache.end() != it_found)
|
||||||
|
return it_found->second;
|
||||||
|
}
|
||||||
|
|
||||||
|
m_query.bind(1, item_id);
|
||||||
|
if (not m_query.executeStep()) {
|
||||||
|
m_query.reset();
|
||||||
|
throw std::runtime_error("No item_id " + std::to_string(item_id) + " found in table items");
|
||||||
|
}
|
||||||
|
|
||||||
|
const int64_t table_id = m_query.getColumn(0);
|
||||||
|
m_query.reset();
|
||||||
|
m_cache[item_id] = table_id;
|
||||||
|
return table_id;
|
||||||
|
}
|
||||||
|
|
||||||
|
private:
|
||||||
|
std::unordered_map<int, int64_t> m_cache;
|
||||||
|
SQLite::Database& m_db;
|
||||||
|
SQLite::Statement m_query;
|
||||||
|
};
|
||||||
|
|
||||||
template <typename CastT=void, typename T=void>
|
template <typename CastT=void, typename T=void>
|
||||||
void bind (SQLite::Statement& st, int idx, const boost::optional<T>& val) {
|
void bind (SQLite::Statement& st, int idx, const boost::optional<T>& val) {
|
||||||
if (val) {
|
if (val) {
|
||||||
|
@ -99,6 +134,21 @@ namespace {
|
||||||
|
|
||||||
return shop;
|
return shop;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
std::string string_query_create_items (std::string_view table) {
|
||||||
|
return std::string(
|
||||||
|
"CREATE TABLE IF NOT EXISTS ").append(table) + " ("
|
||||||
|
"id INTEGER PRIMARY KEY NOT NULL"
|
||||||
|
", item_id INTEGER"
|
||||||
|
", unique_name TEXT"
|
||||||
|
", name TEXT"
|
||||||
|
", type TINYINT"
|
||||||
|
", subtype TINYINT"
|
||||||
|
", npc_price INTEGER"
|
||||||
|
", slots TINYINT"
|
||||||
|
", removal_date TEXT"
|
||||||
|
")";
|
||||||
|
}
|
||||||
} //unnamed namespace
|
} //unnamed namespace
|
||||||
|
|
||||||
OriginsDB::OriginsDB (std::string_view path) :
|
OriginsDB::OriginsDB (std::string_view path) :
|
||||||
|
@ -111,8 +161,6 @@ OriginsDB::~OriginsDB() noexcept = default;
|
||||||
void OriginsDB::update (const Items& items) {
|
void OriginsDB::update (const Items& items) {
|
||||||
Database db(m_db_mutex, m_path);
|
Database db(m_db_mutex, m_path);
|
||||||
|
|
||||||
db.exec("DROP TABLE IF EXISTS items");
|
|
||||||
|
|
||||||
//example:
|
//example:
|
||||||
//{
|
//{
|
||||||
// "item_id":501,
|
// "item_id":501,
|
||||||
|
@ -121,19 +169,21 @@ void OriginsDB::update (const Items& items) {
|
||||||
// "type":"IT_HEALING",
|
// "type":"IT_HEALING",
|
||||||
// "npc_price":50
|
// "npc_price":50
|
||||||
//}
|
//}
|
||||||
db.exec(
|
|
||||||
"CREATE TABLE items ("
|
|
||||||
"item_id INTEGER PRIMARY KEY NOT NULL"
|
|
||||||
", unique_name TEXT UNIQUE"
|
|
||||||
", name TEXT"
|
|
||||||
", type TINYINT"
|
|
||||||
", subtype TINYINT"
|
|
||||||
", npc_price INTEGER"
|
|
||||||
", slots TINYINT"
|
|
||||||
")"
|
|
||||||
);
|
|
||||||
|
|
||||||
SQLite::Statement query(db, "INSERT INTO items(item_id, unique_name, name, type, subtype, npc_price, slots) VALUES(?, ?, ?, ?, ?, ?, ?)");
|
db.exec("DROP TABLE IF EXISTS items_staging");
|
||||||
|
db.exec(string_query_create_items("items_staging"));
|
||||||
|
|
||||||
|
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))");
|
||||||
|
|
||||||
|
SQLite::Statement query(db,
|
||||||
|
"INSERT OR IGNORE INTO items_staging "
|
||||||
|
"(item_id, unique_name, name, type, subtype, npc_price, slots) "
|
||||||
|
"VALUES(?1, ?2, ?3, ?4, ?5, ?6, ?7)"
|
||||||
|
);
|
||||||
|
SQLite::Transaction transaction(db);
|
||||||
for (const auto& item : items.items) {
|
for (const auto& item : items.items) {
|
||||||
query.bind(1, item.item_id);
|
query.bind(1, item.item_id);
|
||||||
query.bind(2, item.unique_name);
|
query.bind(2, item.unique_name);
|
||||||
|
@ -146,6 +196,21 @@ void OriginsDB::update (const Items& items) {
|
||||||
query.exec();
|
query.exec();
|
||||||
query.reset();
|
query.reset();
|
||||||
}
|
}
|
||||||
|
|
||||||
|
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"
|
||||||
|
")"
|
||||||
|
);
|
||||||
|
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"
|
||||||
|
);
|
||||||
|
db.exec("DROP TABLE items_staging");
|
||||||
|
|
||||||
|
transaction.commit();
|
||||||
}
|
}
|
||||||
|
|
||||||
void OriginsDB::update (const Icons& icons) {
|
void OriginsDB::update (const Icons& icons) {
|
||||||
|
@ -216,21 +281,23 @@ void OriginsDB::update (const Shops& shops) {
|
||||||
", creator INTEGER"
|
", creator INTEGER"
|
||||||
", beloved TINYINT"
|
", beloved TINYINT"
|
||||||
", FOREIGN KEY(shop_id) REFERENCES shops(id)"
|
", FOREIGN KEY(shop_id) REFERENCES shops(id)"
|
||||||
|
", FOREIGN KEY(item_id) REFERENCES items(id)"
|
||||||
")"
|
")"
|
||||||
);
|
);
|
||||||
db.exec("CREATE TABLE IF NOT EXISTS slotted_cards("
|
db.exec("CREATE TABLE IF NOT EXISTS slotted_cards("
|
||||||
"id INTEGER PRIMARY KEY NOT NULL"
|
"id INTEGER PRIMARY KEY NOT NULL"
|
||||||
", item_id INTEGER NOT NULL"
|
", shop_item_id INTEGER NOT NULL"
|
||||||
", card_id INTEGER NOT NULL"
|
", card_id INTEGER NOT NULL"
|
||||||
", FOREIGN KEY(item_id) REFERENCES shop_items(id)"
|
", FOREIGN KEY(shop_item_id) REFERENCES shop_items(id)"
|
||||||
//", FOREIGN KEY(card_id) REFERENCES items(item_id)"
|
", FOREIGN KEY(card_id) REFERENCES items(id)"
|
||||||
")"
|
")"
|
||||||
);
|
);
|
||||||
|
|
||||||
SQLite::Statement ins_shop(db, "INSERT INTO shops(title, owner, creation_date, loc_map, loc_x, loc_y, type) VALUES(?, ?, ?, ?, ?, ?, ?)");
|
SQLite::Statement ins_shop(db, "INSERT INTO shops(title, owner, creation_date, loc_map, loc_x, loc_y, type) VALUES(?, ?, ?, ?, ?, ?, ?)");
|
||||||
SQLite::Statement ins_item(db, "INSERT INTO shop_items(shop_id, item_id, amount, price, refine, star_crumbs, element, creator, beloved) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?)");
|
SQLite::Statement ins_item(db, "INSERT INTO shop_items(shop_id, item_id, amount, price, refine, star_crumbs, element, creator, beloved) VALUES(?, ?, ?, ?, ?, ?, ?, ?, ?)");
|
||||||
SQLite::Statement ins_card(db, "INSERT INTO slotted_cards(item_id, card_id) VALUES(?, ?)");
|
SQLite::Statement ins_card(db, "INSERT INTO slotted_cards(shop_item_id, card_id) VALUES(?, ?)");
|
||||||
|
|
||||||
|
ItemIdToTableId item_id_to_table_id(db);
|
||||||
SQLite::Transaction transaction(db);
|
SQLite::Transaction transaction(db);
|
||||||
for (const auto& shop : shops.shops) {
|
for (const auto& shop : shops.shops) {
|
||||||
std::optional<oro::Shop> old_shop = fetch_shop(db, shop.owner, shop.creation_date);
|
std::optional<oro::Shop> old_shop = fetch_shop(db, shop.owner, shop.creation_date);
|
||||||
|
@ -251,7 +318,7 @@ void OriginsDB::update (const Shops& shops) {
|
||||||
const auto shop_id = db.getLastInsertRowid();
|
const auto shop_id = db.getLastInsertRowid();
|
||||||
for (const auto& item : shop.items) {
|
for (const auto& item : shop.items) {
|
||||||
ins_item.bind(1, shop_id);
|
ins_item.bind(1, shop_id);
|
||||||
ins_item.bind(2, item.item_id);
|
ins_item.bind(2, item_id_to_table_id(item.item_id));
|
||||||
ins_item.bind(3, item.amount);
|
ins_item.bind(3, item.amount);
|
||||||
ins_item.bind(4, item.price);
|
ins_item.bind(4, item.price);
|
||||||
ins_item.bind(5, item.refine);
|
ins_item.bind(5, item.refine);
|
||||||
|
@ -262,10 +329,10 @@ void OriginsDB::update (const Shops& shops) {
|
||||||
ins_item.exec();
|
ins_item.exec();
|
||||||
ins_item.reset();
|
ins_item.reset();
|
||||||
|
|
||||||
const auto item_id = db.getLastInsertRowid();
|
const auto shop_item_id = db.getLastInsertRowid();
|
||||||
for (unsigned int card_id : item.cards) {
|
for (unsigned int card_id : item.cards) {
|
||||||
ins_card.bind(1, item_id);
|
ins_card.bind(1, shop_item_id);
|
||||||
ins_card.bind(2, card_id);
|
ins_card.bind(2, item_id_to_table_id(card_id));
|
||||||
ins_card.exec();
|
ins_card.exec();
|
||||||
ins_card.reset();
|
ins_card.reset();
|
||||||
}
|
}
|
||||||
|
|
Loading…
Reference in a new issue