kima2/src/core/database.cpp

437 lines
16 KiB
C++

#include "database.h"
#include <filesystem>
#include <iostream>
#include <stdexcept>
#include <vector>
Database::Database(const std::string& dbname)
{
dbname_ = dbname;
init();
}
Database::Database()
{
namespace fs = std::filesystem;
#if defined(__linux__)
fs::path dbpath = fs::path(std::getenv("HOME")) / ".local/share/kima2-cpp";
#elif defined(__WIN64) || defined(__WIN32)
fs::path dbpath = fs::path(std::getenv("LOCALAPPDATA") / "/kima2-cpp";
#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();
}
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<std::string> sqlStrings{};
std::string sqlCreateKima2{"CREATE TABLE IF NOT EXISTS kima2 ("
"version INTEGER NOT NULL);"
"INSERT INTO kima2 (version) VALUES (1);"};
sqlStrings.push_back(sqlCreateKima2);
std::string sqlCreateSellers{"CREATE TABLE IF NOT EXISTS sellers ("
"id TEXT PRIMARY KEY NOT NULL, "
"seller_no INTEGER, "
"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_id 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_id) REFERENCES sellers(id) 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);
beginTransaction();
for (const auto& sql : sqlStrings) {
exec(sql);
}
endTransaction();
}
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);
int version = getVersion();
switch (version) {
case 0:
createNew();
break;
// perhaps handle upgrades for db schema here...
default:
// Do nothing because we are up-to-date.
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<std::unique_ptr<Seller>>& sellers)
{
int retCode{};
int count{};
sqlite3_stmt* stmt;
beginTransaction();
for (auto& seller : sellers) {
if (seller->getState() == Seller::State::NEW) {
retCode = sqlite3_prepare_v2(
db_,
"INSERT INTO sellers"
" (id, seller_no, first_name, last_name, num_offered_articles)"
" VALUES (:uuid, :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_text(stmt, sqlite3_bind_parameter_index(stmt, ":uuid"),
boost::uuids::to_string(seller->getUuid()).c_str(), -1,
SQLITE_TRANSIENT);
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) {
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 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(seller->getUuid()).c_str(), -1,
SQLITE_TRANSIENT);
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<int>(seller->getArticles(false).size());
retCode =
sqlite3_prepare_v2(db_, "DELETE FROM sellers 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(seller->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);
}
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>& 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<Article*> 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_id, 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_text(stmt, sqlite3_bind_parameter_index(stmt, ":seller_id"),
boost::uuids::to_string(article->getSeller()->getUuid()).c_str(), -1,
SQLITE_TRANSIENT);
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_id = 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_text(stmt, sqlite3_bind_parameter_index(stmt, ":seller_id"),
boost::uuids::to_string(article->getSeller()->getUuid()).c_str(), -1,
SQLITE_TRANSIENT);
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::loadSellers(std::vector<std::unique_ptr<Seller>>& sellers)
{
int retCode{};
int count{};
sqlite3_stmt* stmt;
retCode = sqlite3_prepare_v2(db_,
"SELECT id, 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>();
seller->setUuidFromString(reinterpret_cast<const char*>(sqlite3_column_text(stmt, 0)));
seller->setSellerNo(sqlite3_column_int(stmt, 1));
seller->setFirstName(reinterpret_cast<const char*>(sqlite3_column_text(stmt, 2)));
seller->setLastName(reinterpret_cast<const char*>(sqlite3_column_text(stmt, 3)));
seller->setNumArticlesOffered(sqlite3_column_int(stmt, 4));
seller->setState(Seller::State::OK);
sellers.push_back(std::move(seller));
retCode = sqlite3_step(stmt);
}
sqlite3_finalize(stmt);
return count;
}