#include "database.h" #include #include #include #include #include "boost/date_time/posix_time/posix_time.hpp" Database::Database(const std::string &dbname) { dbname_ = dbname; init(); } Database::Database() { namespace fs = std::filesystem; #if defined(__linux__) || defined(__APPLE__) fs::path dbpath = fs::path(std::getenv("HOME")) / ".local/share/kima2"; #elif defined(_WIN64) || defined(_WIN32) fs::path dbpath = fs::path(std::getenv("LOCALAPPDATA")) / "kima2"; #else throw std::runtime_error("Platform not supported."); #endif if (!fs::exists(dbpath)) { try { fs::create_directories(dbpath); } catch (fs::filesystem_error &err) { throw err; } } dbpath /= "kima2.db"; dbname_ = dbpath.string(); init(); } void Database::newDb() { namespace fs = std::filesystem; sqlite3_close(db_); fs::path sourcePath = dbname_; fs::path destPath = sourcePath.parent_path() / sourcePath.stem(); destPath += std::string("_") += boost::posix_time::to_iso_string(boost::posix_time::second_clock::local_time()) += ".db"; fs::copy_file(sourcePath, destPath, fs::copy_options::overwrite_existing); fs::remove(sourcePath); init(); } Database::~Database() { sqlite3_close(db_); } void Database::exec(const std::string &sql) { char *errMsg; const int errCode = sqlite3_exec(db_, sql.c_str(), nullptr, nullptr, &errMsg); if (errCode) { std::string errMsgString(errMsg); // Make a C++ string of the errMsg, so that we can call // sqlite3_free() before throwing the exception sqlite3_free(errMsg); throw std::runtime_error("Error in SQL execution: " + errMsgString); } } void Database::createNew() { std::vector sqlStrings{}; std::string sqlCreateKima2{"CREATE TABLE IF NOT EXISTS kima2 (" "version INTEGER NOT NULL);" "INSERT INTO kima2 (version) VALUES (3);"}; sqlStrings.push_back(sqlCreateKima2); std::string sqlCreateSellers{"CREATE TABLE IF NOT EXISTS sellers (" "seller_no INTEGER PRIMARY KEY NOT NULL, " "first_name TEXT, " "last_name TEXT, " "num_offered_articles INTEGER, " "UNIQUE (seller_no)" ");"}; sqlStrings.push_back(sqlCreateSellers); std::string sqlCreateArticles{ "CREATE TABLE IF NOT EXISTS articles (" "id TEXT PRIMARY KEY NOT NULL, " "seller_no TEXT NOT NULL, " "source_no INTEGER NOT NULL, " "article_no INTEGER NOT NULL, " "description TEXT, " "price INTEGER NOT NULL, " "UNIQUE (source_no, article_no), " "FOREIGN KEY (seller_no) REFERENCES sellers(seller_no) ON DELETE CASCADE, " "CHECK (article_no BETWEEN 0 AND 99999)" ");"}; sqlStrings.push_back(sqlCreateArticles); std::string sqlCreateSales{"CREATE TABLE IF NOT EXISTS sales (" " id TEXT PRIMARY KEY NOT NULL," " source_no INTEGER NOT NULL," " sold_at TEXT" ");"}; sqlStrings.push_back(sqlCreateSales); std::string sqlCreateSalesItems{ "CREATE TABLE IF NOT EXISTS sales_items(" " sale_id TEXT NOT NULL," " article_id TEXT NOT NULL," " FOREIGN KEY (sale_id) REFERENCES sales(id) ON DELETE CASCADE," " FOREIGN KEY (article_id) REFERENCES articles(id) ON DELETE CASCADE" ");"}; sqlStrings.push_back(sqlCreateSalesItems); std::string sqlInitialEntries{ "INSERT OR IGNORE INTO sellers (seller_no, first_name, last_name, " "num_offered_articles) VALUES " "(0, 'Sonderkonto', 'Sonderkonto', 0)"}; sqlStrings.push_back(sqlInitialEntries); beginTransaction(); for (const auto &sql : sqlStrings) { exec(sql); } endTransaction(); } void Database::updateDbToVer2() { beginTransaction(); exec("INSERT OR IGNORE INTO sellers (seller_no, first_name, last_name, " "num_offered_articles) VALUES " "(0, 'Sonderkonto', 'Sonderkonto', 0)"); exec("UPDATE kima2 SET version = 3"); endTransaction(); } void Database::updateDbToVer3() { newDb(); } void Database::init() { const int errCode = sqlite3_open(dbname_.c_str(), &db_); if (errCode) { throw std::runtime_error("Could not open database file."); } // sqlite3_db_config(db_, SQLITE_DBCONFIG_ENABLE_FKEY); exec("PRAGMA foreign_keys = ON;"); int version = getVersion(); switch (version) { case 0: createNew(); initResult_ = InitResult::OK; break; case 1: updateDbToVer3(); initResult_ = InitResult::OUTDATED_REPLACED; break; case 2: updateDbToVer3(); initResult_ = InitResult::OUTDATED_REPLACED; break; default: // Do nothing because we are up-to-date. initResult_ = InitResult::OK; break; } } int Database::getVersion() { int retCode{}; sqlite3_stmt *stmt; // Check if there's already a kima2 table available. // If not, return version == 0. retCode = sqlite3_prepare_v2( db_, "SELECT count(*) FROM sqlite_master WHERE type='table' AND name='kima2';", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::string(sqlite3_errmsg(db_)); retCode = sqlite3_step(stmt); if (retCode != SQLITE_ROW && retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw errMsg; } else if (retCode != SQLITE_DONE) { int count = sqlite3_column_int(stmt, 0); sqlite3_finalize(stmt); if (count == 0) return 0; // no kima2 table, so version is 0 } // Now that we know that the kima2 table is present, read and return the schema version. retCode = sqlite3_prepare_v2(db_, "SELECT version FROM kima2", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::string(sqlite3_errmsg(db_)); retCode = sqlite3_step(stmt); if (retCode != SQLITE_ROW && retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw errMsg; } else if (retCode == SQLITE_DONE) { sqlite3_finalize(stmt); return 0; // no version entry, so version is 0 } int version = sqlite3_column_int(stmt, 0); sqlite3_finalize(stmt); return version; } void Database::beginTransaction() { exec("BEGIN TRANSACTION"); } void Database::endTransaction() { exec("END TRANSACTION"); } unsigned int Database::storeSellers(std::vector> &sellers, bool onlyDelete) { int retCode{}; int count{}; sqlite3_stmt *stmt; beginTransaction(); for (auto &seller : sellers) { if (seller->getState() == Seller::State::NEW && !onlyDelete) { retCode = sqlite3_prepare_v2( db_, "INSERT INTO sellers" " (seller_no, first_name, last_name, num_offered_articles)" " VALUES (:seller_no, :first_name, :last_name, :num_offered_articles)", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":seller_no"), seller->getSellerNo()); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":first_name"), seller->getFirstName().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":last_name"), seller->getLastName().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":num_offered_articles"), seller->numArticlesOffered()); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } else if (seller->getState() == Seller::State::UPDATE && !onlyDelete) { retCode = sqlite3_prepare_v2( db_, "UPDATE sellers SET" " seller_no = :seller_no, first_name = :first_name," " last_name = :last_name, num_offered_articles = :num_offered_articles" " WHERE seller_no = :id", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":id"), seller->getId()); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":seller_no"), seller->getSellerNo()); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":first_name"), seller->getFirstName().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":last_name"), seller->getLastName().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":num_offered_articles"), seller->numArticlesOffered()); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } else if (seller->getState() == Seller::State::DELETE) { count += static_cast(seller->getArticles(false).size()); retCode = sqlite3_prepare_v2(db_, "DELETE FROM sellers WHERE seller_no = :id", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":id"), seller->getId()); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } if (seller->getState() != Seller::State::DELETE) { count += storeArticles(seller->getArticles(false)); } } endTransaction(); // Everything went fine, so we can now update our objects sellers.erase(std::remove_if(sellers.begin(), sellers.end(), [](const std::unique_ptr &seller) { return (seller->getState() == Seller::State::DELETE); }), sellers.end()); for (auto &seller : sellers) { seller->cleanupArticles(); seller->setState(Seller::State::OK); } return count; } unsigned int Database::storeArticles(std::vector
articles) { int retCode{}; int count{}; sqlite3_stmt *stmt; for (auto &article : articles) { if (article->getState() == Article::State::NEW) { retCode = sqlite3_prepare_v2( db_, "INSERT INTO articles" " (id, seller_no, source_no, article_no, description, price)" " VALUES (:uuid, :seller_id, :source_no, :article_no, :desc, :price)", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"), boost::uuids::to_string(article->getUuid()).c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":seller_id"), article->getSeller()->getId()); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":source_no"), article->getSourceNo()); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":article_no"), article->getArticleNo()); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":desc"), article->getDescription().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":price"), article->getPrice()); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } else if (article->getState() == Article::State::UPDATE) { retCode = sqlite3_prepare_v2( db_, "UPDATE articles SET" " seller_no = :seller_id, source_no = :source_no, article_no = :article_no," " description = :desc, price = :price" " WHERE id = :uuid", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"), boost::uuids::to_string(article->getUuid()).c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":seller_id"), article->getSeller()->getId()); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":source_no"), article->getSourceNo()); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":article_no"), article->getArticleNo()); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":desc"), article->getDescription().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":price"), article->getPrice()); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } else if (article->getState() == Article::State::DELETE) { retCode = sqlite3_prepare_v2(db_, "DELETE FROM articles WHERE id = :uuid", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"), boost::uuids::to_string(article->getUuid()).c_str(), -1, SQLITE_TRANSIENT); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } } return count; } unsigned int Database::storeSales(std::vector> &sales) { int retCode{}; int count{}; sqlite3_stmt *stmt; if (sales.size() == 0) return 0; beginTransaction(); for (auto &sale : sales) { if (sale->getState() == Sale::State::NEW) { retCode = sqlite3_prepare_v2(db_, "INSERT INTO sales" " (id, source_no, sold_at)" " VALUES (:uuid, :source_no, :sold_at)", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"), boost::uuids::to_string(sale->getUuid()).c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":source_no"), sale->getSourceNo()); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":sold_at"), sale->getTimestamp().c_str(), -1, SQLITE_TRANSIENT); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); for (const auto &article : sale->getArticles()) { retCode = sqlite3_prepare_v2(db_, "INSERT INTO sales_items" " (sale_id, article_id)" " VALUES (:sale_id, :article_id)", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":sale_id"), sale->getUuidAsString().c_str(), -1, SQLITE_TRANSIENT); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":article_id"), article->getUuidAsString().c_str(), -1, SQLITE_TRANSIENT); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } sqlite3_finalize(stmt); } } else if (sale->getState() == Sale::State::DELETE) { retCode = sqlite3_prepare_v2(db_, "DELETE FROM sales WHERE id = :uuid", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"), sale->getUuidAsString().c_str(), -1, SQLITE_TRANSIENT); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } ++count; sqlite3_finalize(stmt); } } endTransaction(); // Everything went fine, so we can now update our objects sales.erase( std::remove_if(sales.begin(), sales.end(), [](const auto &sale) { return (sale->getState() == Sale::State::DELETE); }), sales.end()); for (auto &sale : sales) { sale->setState(Sale::State::OK); } return count; } unsigned int Database::loadSellers(std::vector> &sellers) { int retCode{}; int count{}; sqlite3_stmt *stmt; retCode = sqlite3_prepare_v2(db_, "SELECT seller_no, first_name, last_name, " "num_offered_articles FROM sellers ORDER BY seller_no", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); retCode = sqlite3_step(stmt); sellers.clear(); while (retCode != SQLITE_DONE) { ++count; auto seller = std::make_unique(); seller->setSellerNo(sqlite3_column_int(stmt, 0)); seller->setFirstName(reinterpret_cast(sqlite3_column_text(stmt, 1))); seller->setLastName(reinterpret_cast(sqlite3_column_text(stmt, 2))); seller->setNumArticlesOffered(sqlite3_column_int(stmt, 3)); seller->setState(Seller::State::OK); sellers.push_back(std::move(seller)); retCode = sqlite3_step(stmt); } sqlite3_finalize(stmt); for (auto &seller : sellers) { retCode = sqlite3_prepare_v2(db_, "SELECT id, source_no, article_no, description, price" " FROM articles" " WHERE seller_no = :seller_id" " ORDER BY article_no", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":seller_id"), seller->getId()); retCode = sqlite3_step(stmt); while (retCode != SQLITE_DONE) { ++count; auto article = std::make_unique
(); article->setUuidFromString( reinterpret_cast(sqlite3_column_text(stmt, 0))); article->setSeller(seller.get()); article->setSourceNo(sqlite3_column_int(stmt, 1)); article->setArticleNo(sqlite3_column_int(stmt, 2)); article->setDescription(reinterpret_cast(sqlite3_column_text(stmt, 3))); article->setPrice(sqlite3_column_int(stmt, 4)); article->setState(Article::State::OK); seller->addArticle(std::move(article)); retCode = sqlite3_step(stmt); } sqlite3_finalize(stmt); } return count; } unsigned int Database::loadSales(std::vector> &sales, std::vector> &sellers) { int retCode{}; int count{}; sqlite3_stmt *stmt; retCode = sqlite3_prepare_v2(db_, "SELECT id, source_no, sold_at" " FROM sales ORDER BY sold_at DESC", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); retCode = sqlite3_step(stmt); sales.clear(); std::map saleMap; while (retCode != SQLITE_DONE) { ++count; auto sale = std::make_unique(); sale->setUuidFromString(reinterpret_cast(sqlite3_column_text(stmt, 0))); sale->setSourceNo(sqlite3_column_int(stmt, 1)); sale->setTimestamp(reinterpret_cast(sqlite3_column_text(stmt, 2))); sale->setState(Sale::State::OK); saleMap.insert(std::make_pair(sale->getUuidAsString(), sale.get())); sales.push_back(std::move(sale)); retCode = sqlite3_step(stmt); } sqlite3_finalize(stmt); std::map artMap; for (const auto &seller : sellers) { for (const auto article : seller->getArticles(false)) { artMap.insert(std::make_pair(article->getUuidAsString(), article)); } } retCode = sqlite3_prepare_v2(db_, "SELECT sale_id, article_id" " FROM sales_items", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::runtime_error(sqlite3_errmsg(db_)); retCode = sqlite3_step(stmt); while (retCode != SQLITE_DONE) { saleMap[reinterpret_cast(sqlite3_column_text(stmt, 0))]->addArticle( artMap[reinterpret_cast(sqlite3_column_text(stmt, 1))]); retCode = sqlite3_step(stmt); } sqlite3_finalize(stmt); return count; } void Database::updateCashPointNo(int oldCashPointNo, int newCashPointNo) { int retCode{}; sqlite3_stmt *stmt; // Check if the new no ist already in use retCode = sqlite3_prepare_v2(db_, "SELECT COUNT() FROM articles WHERE source_no = :source_no", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::string(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":source_no"), newCashPointNo); retCode = sqlite3_step(stmt); int count{}; if (retCode != SQLITE_ROW) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } count = sqlite3_column_int(stmt, 0); sqlite3_finalize(stmt); if (count > 0) { throw std::runtime_error("The desired cashpoint no is aleady in use."); } beginTransaction(); retCode = sqlite3_prepare_v2( db_, "UPDATE articles SET source_no = :new_source_no WHERE source_no = :old_source_no", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::string(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":new_source_no"), newCashPointNo); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":old_source_no"), oldCashPointNo); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } sqlite3_finalize(stmt); retCode = sqlite3_prepare_v2( db_, "UPDATE sales SET source_no = :new_source_no WHERE source_no = :old_source_no", -1, &stmt, nullptr); if (retCode != SQLITE_OK) throw std::string(sqlite3_errmsg(db_)); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":new_source_no"), newCashPointNo); sqlite3_bind_int(stmt, sqlite3_bind_parameter_index(stmt, ":old_source_no"), oldCashPointNo); retCode = sqlite3_step(stmt); if (retCode != SQLITE_DONE) { std::string errMsg(sqlite3_errmsg(db_)); sqlite3_finalize(stmt); throw std::runtime_error(errMsg); } sqlite3_finalize(stmt); endTransaction(); }