query/test/session.cpp

315 lines
9.1 KiB
C++

#include <catch2/catch_test_macros.hpp>
#include <matador/sql/column.hpp>
#include <matador/sql/condition.hpp>
#include <matador/sql/session.hpp>
#include "models/product.hpp"
#include "models/airplane.hpp"
#include "models/flight.hpp"
#include "models/person.hpp"
using namespace matador::sql;
using namespace matador::test;
TEST_CASE("Create and drop table statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<unsigned short>("age")
}).execute();
REQUIRE(res.second == R"(CREATE TABLE "person" ("id" BIGINT NOT NULL, "name" VARCHAR(255), "age" INTEGER, CONSTRAINT PK_person PRIMARY KEY (id)))");
res = s.drop().table("person").execute();
REQUIRE(res.second == R"(DROP TABLE "person")");
}
TEST_CASE("Create table with foreign key relation", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create().table<airplane>("airplane").execute();
REQUIRE(res.first == 0);
REQUIRE(res.second == R"(CREATE TABLE "airplane" ("id" BIGINT, "brand" VARCHAR(255), "model" VARCHAR(255), CONSTRAINT PK_airplane PRIMARY KEY (id)))");
res = s.create().table<flight>("flight").execute();
REQUIRE(res.first == 0);
REQUIRE(res.second == R"(CREATE TABLE "flight" ("id" BIGINT, "airplane_id" BIGINT, "pilot_name" VARCHAR(255), CONSTRAINT PK_flight PRIMARY KEY (id), CONSTRAINT FK_flight_airplane_id FOREIGN KEY (airplane_id) REFERENCES airplane(id)))");
s.drop().table("flight").execute();
s.drop().table("airplane").execute();
}
TEST_CASE("Execute insert record statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s
.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<unsigned short>("age")
})
.execute();
REQUIRE(res.first == 0);
res = s
.insert()
.into("person", {"id", "name", "age"})
.values({7, "george", 45})
.execute();
REQUIRE(res.first == 1);
REQUIRE(res.second == R"(INSERT INTO "person" ("id", "name", "age") VALUES (7, 'george', 45))");
auto result = s
.select({"id", "name", "age"})
.from("person")
.fetch_all();
for (const auto& i : result) {
REQUIRE(i.size() == 3);
REQUIRE(i.at(0).name() == "id");
REQUIRE(i.at(0).type() == data_type_t::type_long_long);
REQUIRE(i.at(0).value<long long>() == 7);
REQUIRE(i.at(1).name() == "name");
REQUIRE(i.at(1).type() == data_type_t::type_varchar);
REQUIRE(i.at(1).value<std::string>() == "george");
REQUIRE(i.at(2).name() == "age");
REQUIRE(i.at(2).type() == matador::sql::data_type_t::type_int);
REQUIRE(i.at(2).value<int>() == 45);
}
s.drop().table("person").execute();
}
TEST_CASE("Execute update record statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s
.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<unsigned short>("age")
})
.execute();
REQUIRE(res.first == 0);
res = s
.insert()
.into("person", {"id", "name", "age"})
.values({7, "george", 45})
.execute();
REQUIRE(res.first == 1);
REQUIRE(res.second == R"(INSERT INTO "person" ("id", "name", "age") VALUES (7, 'george', 45))");
res = s.update("person")
.set({{"id", 7}, {"name", "jane"}, {"age", 35}})
.where("id"_col == 7)
.execute();
REQUIRE(res.first == 1);
REQUIRE(res.second == R"(UPDATE "person" SET "id"=7, "name"='jane', "age"=35 WHERE "id" = 7)");
auto result = s
.select({"id", "name", "age"})
.from("person")
.fetch_all();
for (const auto& i : result) {
REQUIRE(i.size() == 3);
REQUIRE(i.at(0).name() == "id");
REQUIRE(i.at(0).type() == data_type_t::type_long_long);
REQUIRE(i.at(0).value<long long>() == 7);
REQUIRE(i.at(1).name() == "name");
REQUIRE(i.at(1).type() == data_type_t::type_varchar);
REQUIRE(i.at(1).value<std::string>() == "jane");
REQUIRE(i.at(2).name() == "age");
REQUIRE(i.at(2).type() == matador::sql::data_type_t::type_int);
REQUIRE(i.at(2).value<int>() == 35);
}
s.drop().table("person").execute();
}
TEST_CASE("Execute select statement with where clause", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table<person>("person")
.execute();
REQUIRE(res.first == 0);
person george{7, "george", 45};
res = s.insert()
.into("person", george)
.execute();
REQUIRE(res.first == 1);
auto result = s.select<person>()
.from("person")
.where("id"_col == 7)
.fetch_all();
for (const auto& i : result) {
REQUIRE(i.size() == 3);
REQUIRE(i.at(0).name() == "id");
REQUIRE(i.at(0).type() == data_type_t::type_long_long);
REQUIRE(i.at(0).value<long long>() == george.id);
REQUIRE(i.at(1).name() == "name");
REQUIRE(i.at(1).type() == data_type_t::type_varchar);
REQUIRE(i.at(1).value<std::string>() == george.name);
REQUIRE(i.at(2).name() == "age");
REQUIRE(i.at(2).type() == matador::sql::data_type_t::type_long_long);
REQUIRE(i.at(2).value<long long>() == george.age);
}
// REQUIRE(res.str() == R"(SELECT "id", "name", "color" FROM "person" WHERE "id" = 8)");
s.drop().table("person").execute();
}
TEST_CASE("Execute select statement with order by", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s
.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<std::string>("color", 63)
})
.execute();
REQUIRE(res.first == 0);
auto result = s.select({"id", "name", "color"})
.from("person")
.where("id"_col == 8)
.order_by("name").desc()
.fetch_all();
// Todo: prepare test data
s.drop().table("person").execute();
}
TEST_CASE("Execute select statement with group by and order by", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<std::string>("color", 63)
})
.execute();
auto result = s.select({"id", "name", "color"})
.from("person")
.where("id"_col == 8)
.group_by("color")
.order_by("name").asc()
.fetch_all();
// Todo: prepare test data
s.drop().table("person").execute();
}
TEST_CASE("Execute insert statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<std::string>("color", 63)
})
.execute();
res = s.insert()
.into("person", {"id", "name", "color"})
.values({7, "george", "green"})
.execute();
REQUIRE(res.first == 1);
REQUIRE(res.second == R"(INSERT INTO "person" ("id", "name", "color") VALUES (7, 'george', 'green'))");
s.drop().table("person").execute();
}
TEST_CASE("Execute update statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<std::string>("color", 63)
})
.execute();
res = s.insert()
.into("person", {"id", "name", "color"})
.values({7, "george", "green"})
.execute();
REQUIRE(res.first == 1);
REQUIRE(res.second == R"(INSERT INTO "person" ("id", "name", "color") VALUES (7, 'george', 'green'))");
res = s.update("person")
.set({
{"name", "george"},
{"color", "green"}
})
.where("id"_col == 9)
.execute();
REQUIRE(res.second == R"(UPDATE "person" SET "name"='george', "color"='green' WHERE "id" = 9)");
s.drop().table("person").execute();
}
TEST_CASE("Execute delete statement", "[session]") {
connection_pool<connection> pool("sqlite://sqlite.db", 4);
session s(pool);
auto res = s.create()
.table("person", {
make_pk_column<unsigned long>("id"),
make_column<std::string>("name", 255),
make_column<unsigned short>("age")
}).execute();
REQUIRE(res.first == 0);
res = s.remove()
.from("person")
.where("id"_col == 9)
.execute();
REQUIRE(res.second == R"(DELETE FROM "person" WHERE "id" = 9)");
REQUIRE(s.drop().table("person").execute().first == 0);
}