Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Migrate dataset to SQLite database & Add SQL and TSV metadata exports #32

Merged
merged 16 commits into from
Jun 28, 2024

Conversation

YourMJK
Copy link
Owner

@YourMJK YourMJK commented Jun 26, 2024

Migrate dataset to SQLite database (#14)

Based on the new relational model (see #23), migrated the JSON dataset to a new SQLite database using the schema below.

Changes:

  • Refined relational model
  • Updated migrate subcommand to create SQLite database using GRDB.swift

Add SQL and TSV metadata exports

Added exported database as SQL dump (metadata/db.sql) and TSV files (metadata/tsv/).

New subcommands:

  • export tsv: Export database as TSV files.
  • export sql: Dump database to SQL format.
  • load: Load database from SQL dump.

CREATE TABLE "hörspiel"(
    "hörspielID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "titel" TEXT NOT NULL,
    "kurzbeschreibung" TEXT,
    "beschreibung" TEXT,
    "metabeschreibung" TEXT,
    "veröffentlichungsdatum" DATE,
    "unvollständig" BOOLEAN NOT NULL,
    "cover" BOOLEAN NOT NULL,
    "urlCoverApple" TEXT,
    "urlCoverKosmos" TEXT
);
CREATE TABLE "hörspielTeil"(
    "teil" INTEGER PRIMARY KEY NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "hörspiel" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "position" INTEGER NOT NULL CHECK("position" > 0),
    "buchstabe" TEXT CHECK(LENGTH("buchstabe") = 1),
    UNIQUE("hörspiel", "position"),
    UNIQUE("hörspiel", "buchstabe")
);

CREATE TABLE "serie"(
    "nummer" INTEGER PRIMARY KEY NOT NULL,
    "hörspielID" INTEGER NOT NULL UNIQUE REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE "spezial"(
    "hörspielID" INTEGER PRIMARY KEY NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE "kurzgeschichten"(
    "hörspielID" INTEGER PRIMARY KEY NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE "dieDr3i"(
    "nummer" INTEGER PRIMARY KEY NOT NULL,
    "hörspielID" INTEGER NOT NULL UNIQUE REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE
);

CREATE TABLE "medium"(
    "mediumID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "hörspielID" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "position" INTEGER NOT NULL CHECK("position" > 0),
    "xldLog" BOOLEAN NOT NULL,
    UNIQUE("hörspielID", "position")
);
CREATE TABLE "track"(
    "trackID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "mediumID" INTEGER NOT NULL REFERENCES "medium"("mediumID") ON DELETE CASCADE ON UPDATE CASCADE,
    "position" INTEGER NOT NULL CHECK("position" > 0),
    "titel" TEXT NOT NULL,
    "dauer" INTEGER NOT NULL CHECK("dauer" > 0),
    UNIQUE("mediumID", "position")
);
CREATE TABLE "kapitel"(
    "trackID" INTEGER PRIMARY KEY NOT NULL REFERENCES "track"("trackID") ON DELETE CASCADE ON UPDATE CASCADE,
    "hörspielID" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "position" INTEGER NOT NULL CHECK("position" > 0),
    "abweichenderTitel" TEXT,
    UNIQUE("hörspielID", "position")
);

CREATE TABLE "person"(
    "personID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "name" TEXT NOT NULL UNIQUE
);
CREATE TABLE "pseudonym"(
    "pseudonymID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "name" TEXT NOT NULL UNIQUE
);
CREATE TABLE "rolle"(
    "rolleID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "name" TEXT NOT NULL UNIQUE
);
CREATE TABLE "sprechrolle"(
    "sprechrolleID" INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
    "hörspielID" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "rolleID" INTEGER NOT NULL REFERENCES "rolle"("rolleID") ON DELETE CASCADE ON UPDATE CASCADE,
    "position" INTEGER NOT NULL CHECK("position" > 0),
    UNIQUE("hörspielID", "rolleID"),
    UNIQUE("hörspielID", "position")
);
CREATE TABLE "spricht"(
    "sprechrolleID" INTEGER NOT NULL REFERENCES "sprechrolle"("sprechrolleID") ON DELETE CASCADE ON UPDATE CASCADE,
    "personID" INTEGER NOT NULL REFERENCES "person"("personID") ON DELETE CASCADE ON UPDATE CASCADE,
    "pseudonymID" INTEGER REFERENCES "pseudonym"("pseudonymID") ON DELETE SET NULL ON UPDATE CASCADE,
    PRIMARY KEY("sprechrolleID", "personID")
);

CREATE TABLE "hörspielBuchautor"(
    "hörspielID" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "personID" INTEGER NOT NULL REFERENCES "person"("personID") ON DELETE CASCADE ON UPDATE CASCADE,
    PRIMARY KEY("hörspielID", "personID")
);
CREATE TABLE "hörspielSkriptautor"(
    "hörspielID" INTEGER NOT NULL REFERENCES "hörspiel"("hörspielID") ON DELETE CASCADE ON UPDATE CASCADE,
    "personID" INTEGER NOT NULL REFERENCES "person"("personID") ON DELETE CASCADE ON UPDATE CASCADE,
    PRIMARY KEY("hörspielID", "personID")
);

@YourMJK YourMJK added the Erweiterung Neues Feature oder Wunsch label Jun 26, 2024
@YourMJK YourMJK added this to the v2.0 milestone Jun 26, 2024
@YourMJK YourMJK self-assigned this Jun 26, 2024
@YourMJK YourMJK merged commit b75dd65 into v2.0 Jun 28, 2024
@YourMJK YourMJK deleted the sql-database branch June 28, 2024 23:32
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
Erweiterung Neues Feature oder Wunsch
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

1 participant