#include "ocdb.h" #include "debug.h" #include "okapi.h" #include #include #include #include #include using json = nlohmann::json; // using namespace std::literals::string_literals; OCdb::OCdb(const Service service) { int res; switch (service) { case ocpl: res = sqlite3_open(Database_pl, &db); break; case ocde: res = sqlite3_open(Database_de, &db); break; case ocus: res = sqlite3_open(Database_us, &db); default: throw 1; } if (res != SQLITE_OK) { Debug(1) << sqlite3_errmsg(db); throw 1; } if (!read_revision()) { Debug(1) << "Error reading database revision, database may be corrupt or empty.\n"; } } OCdb::~OCdb() { sqlite3_close(db); } bool OCdb::request(const std::string& req) const { int res; res = sqlite3_prepare_v2(db, req.c_str(), req.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << req << "\" failed:\n" << sqlite3_errmsg(db); return 0; } res = sqlite3_step(stmt); if (res != SQLITE_DONE) { Debug(1) << "Request \"" << req << "\" failed:\n" << sqlite3_errmsg(db); return 0; } sqlite3_finalize(stmt); return 1; } bool OCdb::init(const std::string& dump_path) { request("BEGIN TRANSACTION;"); if (!request("DROP TABLE IF EXISTS caches;") || !request("DROP TABLE IF EXISTS logs;") || !request("DROP TABLE IF EXISTS revision;")) throw 1; if (!request("CREATE TABLE IF NOT EXISTS revision (revision INTEGER PRIMARY KEY);") || !request("CREATE TABLE IF NOT EXISTS caches (code TEXT PRIMARY KEY, name TEXT, location TEXT, type TEXT, status INTEGER, size TEXT, difficulty INTEGER, terrain INTEGER, country TEXT, region TEXT, owner TEXT);") || !request("CREATE TABLE IF NOT EXISTS logs (uuid TEXT PRIMARY KEY, cache_code TEXT, date TEXT, user TEXT, type INTEGER);") || !request("CREATE INDEX idx_user on logs (user, type);")) throw 1; request("COMMIT;"); std::ifstream file(dump_path + "index.json"); json j; file >> j; revision = j["revision"]; request("BEGIN TRANSACTION;"); request("INSERT INTO revision VALUES (" + std::to_string(revision) + ");"); for (auto& el : j["data_files"].items()) { init_part(dump_path + el.value().get()); } request("COMMIT;"); return 1; } bool OCdb::init_part(const std::string& json_file) { Debug(2) << "Processing file: " << json_file << '\n'; std::ifstream file(json_file); json j; file >> j; Debug(5) << "File: " << json_file << " read.\n"; for (auto& el : j.items()) { parse_item(el.value()); } return 1; } bool OCdb::update(const Okapi& oc) { if (revision == 0) { Debug(1) << "Cannot update database, you need to init it first with a full dump.\n"; throw 1; } Debug(2) << "Fetching changelog since revision " << revision << ".\n"; std::string output = oc.get_changelog_json(revision); json j = json::parse(output); request("BEGIN TRANSACTION;"); for (auto& el : j["changelog"].items()) { parse_item(el.value()); } set_revision(j["revision"]); request("COMMIT;"); if (j["more"]) update(oc); return 1; } bool OCdb::parse_item(const json& j) { if (j.count("object_type") && j["object_type"] == "geocache") { if (j.count("change_type") && j["change_type"] == "replace") { Debug(5) << "Inserting/updating cache " << j["object_key"]["code"].get() << ".\n"; // if (j["object_key"]["code"] != j["data"]["code"]) { // Debug(1) << "Code change " << j["object_key"]["code"] << " -> " << j["data"]["code"] <<'\n'; // } update_cache(j); } else if (j.count("change_type") && j["change_type"] == "delete") { Debug(2) << "Deleting cache " << j["object_key"]["code"].get() << ".\n"; sql = "DELETE FROM caches WHERE code='" + j["object_key"]["code"].get() + "';"; request(sql); } else { Debug(1) << "Incorrect change type: " << j["change_type"] << ".\n"; } } else if (j.count("object_type") && j["object_type"] == "log") { if (j["change_type"] == "replace") { Debug(3) << "Updating log " << j["object_key"]["uuid"] << ".\n"; update_log(j); } else if (j.count("change_type") && j["change_type"] == "delete") { Debug(2) << "Deleting log " << j["object_key"]["uuid"] << ".\n"; sql = "DELETE FROM logs WHERE uuid='" + j["object_key"]["uuid"].get() + "';"; request(sql); } else { Debug(1) << "Incorrect change type: " << j["change_type"] << ".\n"; } } else { Debug(1) << "Incorrect object type: " << j["object_type"] << ".\n"; } return 1; } bool OCdb::update_cache(const json& j) { // (code TEXT PRIMARY KEY, name TEXT, location TEXT, type TEXT, status INTEGER, size TEXT, difficulty INTEGER, terrain INTEGER, country TEXT, region TEXT, owner TEXT) std::map fields; std::map fields2; int res; if (!j.count("object_key") || !j["object_key"].count("code") || !j.count("data")) return 0; std::string code = j["object_key"]["code"].get(); if (j["data"].count("names") && j["data"]["names"].count("pl") && !j["data"]["names"]["pl"].is_null()) fields["name"] = j["data"]["names"]["pl"].get(); else if (j["data"].count("names") && j["data"]["names"].count("en") && !j["data"]["names"]["en"].is_null()) fields["name"] = j["data"]["names"]["en"].get(); else if (j["data"].count("names") && j["data"]["names"].count("de") && !j["data"]["names"]["de"].is_null()) fields["name"] = j["data"]["names"]["de"].get(); if (j["data"].count("location") && !j["data"]["location"].is_null()) fields["location"] = j["data"]["location"].get(); if (j["data"].count("type") && !j["data"]["type"].is_null()) fields["type"] = j["data"]["type"].get(); if (j["data"].count("status") && !j["data"]["status"].is_null()) { std::string tmp = j["data"]["status"].get(); if (tmp == "Available") fields2["status"] = ok; else if (tmp == "Archived") fields2["status"] = archived; else if (tmp == "Temporarily unavailable") fields2["status"] = disabled; else fields2["status"] = unknown; } if (j["data"].count("size2") && !j["data"]["size2"].is_null()) fields["size"] = j["data"]["size2"].get(); if (j["data"].count("difficulty") && !j["data"]["difficulty"].is_null()) fields2["difficulty"] = 2 * j["data"]["difficulty"].get(); if (j["data"].count("terrain") && !j["data"]["terrain"].is_null()) fields2["terrain"] = 2 * j["data"]["terrain"].get(); if (j["data"].count("country") && !j["data"]["country"].is_null()) fields["country"] = j["data"]["country"].get(); if (j["data"].count("region") && !j["data"]["region"].is_null()) fields["region"] = j["data"]["region"].get(); else if (j["data"].count("state") && !j["data"]["state"].is_null()) fields["region"] = j["data"]["state"].get(); if (j["data"].count("owner") && j["data"]["owner"].count("uuid") && !j["data"]["owner"]["uuid"].is_null()) fields["owner"] = j["data"]["owner"]["uuid"].get(); if (fields.empty() && fields2.empty()) return 1; sql = "INSERT INTO caches (code,"; for (const auto& i : fields) sql += i.first + ','; for (const auto& i : fields2) sql += i.first + ','; sql.pop_back(); sql += ") VALUES ('" + code + "',"; for (__attribute__((unused)) const auto& i : fields) sql += "?,"; for (__attribute__((unused)) const auto& i : fields2) sql += "?,"; sql.pop_back(); sql += ") ON CONFLICT(code) DO UPDATE SET "; for (const auto& i : fields) sql += i.first + "=excluded." + i.first + ','; for (const auto& i : fields2) sql += i.first + "=excluded." + i.first + ','; sql.pop_back(); sql += ';'; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } int n = 1; for (const auto& i : fields) { sqlite3_bind_text(stmt, n++, i.second.c_str(), -1, nullptr); } for (const auto& i : fields2) { sqlite3_bind_int(stmt, n++, i.second); } res = sqlite3_step(stmt); if (res != SQLITE_DONE) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } sqlite3_finalize(stmt); return 1; } bool OCdb::update_log(const json& j) { // logs (uuid TEXT PRIMARY KEY, cache_code TEXT, date TEXT, user TEXT, type TEXT);")) std::map fields; std::map fields2; int res; if (!j.count("object_key") || !j["object_key"].count("uuid") || !j.count("data")) return 0; std::string uuid = j["object_key"]["uuid"].get(); if (j["data"].count("cache_code") && !j["data"]["cache_code"].is_null()) fields["cache_code"] = j["data"]["cache_code"].get(); if (j["data"].count("date") && !j["data"]["date"].is_null()) fields["date"] = j["data"]["date"].get(); if (j["data"].count("user") && j["data"]["user"].count("uuid") && !j["data"]["user"]["uuid"].is_null()) fields["user"] = j["data"]["user"]["uuid"].get(); if (j["data"].count("type") && !j["data"]["type"].is_null()) { if (j["data"]["type"].get() == "Didn't find it") fields2["type"] = dnf; else if (j["data"]["type"].get() == "Found it") fields2["type"] = found; else fields2["type"] = other; } if (fields.empty()) return 1; sql = "INSERT INTO logs (uuid,"; for (const auto& i : fields) sql += i.first + ','; for (const auto& i : fields2) sql += i.first + ','; sql.pop_back(); sql += ") VALUES ('" + uuid + "',"; for (__attribute__((unused)) const auto& i : fields) sql += "?,"; for (__attribute__((unused)) const auto& i : fields2) sql += "?,"; sql.pop_back(); sql += ") ON CONFLICT(uuid) DO UPDATE SET "; for (const auto& i : fields) sql += i.first + "=excluded." + i.first + ','; sql.pop_back(); sql += ';'; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } int n = 1; for (const auto& i : fields) { sqlite3_bind_text(stmt, n++, i.second.c_str(), -1, nullptr); } for (const auto& i : fields2) { sqlite3_bind_int(stmt, n++, i.second); } res = sqlite3_step(stmt); if (res != SQLITE_DONE) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } sqlite3_finalize(stmt); return 1; } bool OCdb::read_revision() { int res; sql = "SELECT revision FROM revision;"; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } res = sqlite3_step(stmt); if (res != SQLITE_ROW) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); return 0; } revision = sqlite3_column_int(stmt, 0); sqlite3_finalize(stmt); Debug(2) << "Revision: " << revision << '\n'; return 1; } Caches OCdb::get_user_caches_not_found(const std::string& uuid) const { int res; Caches cc; sql = "SELECT code, location, region FROM caches WHERE status = "; sql += std::to_string(ok); sql += " AND NOT EXISTS (SELECT cache_code FROM logs WHERE cache_code = code AND type = "; sql += std::to_string(found); sql += " and user = ?1) AND owner != ?1;"; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } sqlite3_bind_text(stmt, 1, uuid.c_str(), -1, nullptr); res = sqlite3_step(stmt); while (res == SQLITE_ROW) { Cache c; if (sqlite3_column_text(stmt, 0)) c.code = reinterpret_cast(sqlite3_column_text(stmt, 0)); if (sqlite3_column_text(stmt, 1)) c.pos = Position(reinterpret_cast(sqlite3_column_text(stmt, 1))); if (sqlite3_column_text(stmt, 2)) c.region = reinterpret_cast(sqlite3_column_text(stmt, 2)); c.status = ok; cc.push_back(c); res = sqlite3_step(stmt); } if (res != SQLITE_DONE) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } sqlite3_finalize(stmt); return cc; } Caches OCdb::get_user_caches(const std::string& uuid, __attribute__((unused)) int count) const { int res; //code TEXT PRIMARY KEY, name TEXT, location TEXT, type TEXT, status INTEGER, size TEXT, difficulty INTEGER, terrain INTEGER, country TEXT, region TEXT, owner TEXT) sql = "SELECT code, location, type, size, difficulty, terrain, country, region, owner, status, name, country FROM caches WHERE EXISTS (SELECT cache_code FROM logs WHERE cache_code = code AND type = "; sql += std::to_string(found); sql += " and user = ?);"; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } sqlite3_bind_text(stmt, 1, uuid.c_str(), -1, nullptr); return parse_sql_caches(); } Caches OCdb::get_user_caches_owned(const std::string& uuid) const { int res; //code TEXT PRIMARY KEY, name TEXT, location TEXT, type TEXT, status TEXT, size TEXT, difficulty INTEGER, terrain INTEGER, country TEXT, region TEXT, owner TEXT) sql = "SELECT code, location, type, size, difficulty, terrain, country, region, owner, status, name, country FROM caches WHERE owner = ?;"; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } sqlite3_bind_text(stmt, 1, uuid.c_str(), -1, nullptr); return parse_sql_caches(); } Caches OCdb::parse_sql_caches() const { int res; Caches cc; res = sqlite3_step(stmt); while (res == SQLITE_ROW) { Cache c; if (sqlite3_column_text(stmt, 0)) c.code = reinterpret_cast(sqlite3_column_text(stmt, 0)); if (sqlite3_column_text(stmt, 1)) c.pos = Position(reinterpret_cast(sqlite3_column_text(stmt, 1))); if (sqlite3_column_text(stmt, 2)) c.type = reinterpret_cast(sqlite3_column_text(stmt, 2)); if (sqlite3_column_text(stmt, 3)) c.size = reinterpret_cast(sqlite3_column_text(stmt, 3)); c.diff = sqlite3_column_int(stmt, 4) / 2.0; c.terr = sqlite3_column_int(stmt, 5) / 2.0; //c.country = reinterpret_cast(sqlite3_column_text(stmt, 6)); if (sqlite3_column_text(stmt, 7)) c.region = reinterpret_cast(sqlite3_column_text(stmt, 7)); if (sqlite3_column_text(stmt, 8)) c.owner_uuid = reinterpret_cast(sqlite3_column_text(stmt, 8)); // TODO: we don't know owner's nick if (sqlite3_column_text(stmt, 9)) c.status = static_cast(sqlite3_column_int(stmt, 9)); else c.status = unknown; if (sqlite3_column_text(stmt, 10)) c.name = reinterpret_cast(sqlite3_column_text(stmt, 10)); if (sqlite3_column_text(stmt, 11)) c.country = reinterpret_cast(sqlite3_column_text(stmt, 11)); cc.push_back(c); res = sqlite3_step(stmt); } if (res != SQLITE_DONE) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } sqlite3_finalize(stmt); return cc; } int OCdb::get_revision() const { return revision; } void OCdb::set_revision(int rev) { revision = rev; request("UPDATE revision SET revision = " + std::to_string(revision) + ';'); } std::map OCdb::get_region_stats() { std::map count; int res; std::vector regions = { "dolnośląskie", "śląskie", "kujawsko-pomorskie", "łódzkie", "lubelskie", "lubuskie", "małopolskie", "mazowieckie", "opolskie", "podkarpackie", "podlaskie", "pomorskie", "świętokrzyskie", "warmińsko-mazurskie", "wielkopolskie", "zachodniopomorskie" }; //code TEXT PRIMARY KEY, name TEXT, location TEXT, type TEXT, status INTEGER, size TEXT, difficulty INTEGER, terrain INTEGER, country TEXT, region TEXT, owner TEXT) sql = "SELECT COUNT(code) FROM caches WHERE status = "; sql += std::to_string(ok); sql += " AND region = ?;"; res = sqlite3_prepare_v2(db, sql.c_str(), sql.length() + 1, &stmt, NULL); if (res != SQLITE_OK) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } for (const auto& reg : regions) { sqlite3_bind_text(stmt, 1, reg.c_str(), -1, nullptr); res = sqlite3_step(stmt); if (res != SQLITE_ROW) { Debug(1) << "Request \"" << sql << "\" failed:\n" << sqlite3_errmsg(db); throw 0; } count[reg] = sqlite3_column_int(stmt, 0); sqlite3_reset(stmt); sqlite3_clear_bindings(stmt); } sqlite3_finalize(stmt); return count; }