Files
SemesterapparatsManager/src/database/migrations/V001__create_base_tables.sql

133 lines
3.6 KiB
SQL

BEGIN TRANSACTION;
CREATE TABLE IF NOT EXISTS semesterapparat (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
name TEXT,
prof_id INTEGER,
fach TEXT,
appnr INTEGER,
erstellsemester TEXT,
verlängert_am TEXT,
dauer BOOLEAN,
verlängerung_bis TEXT,
deletion_status INTEGER,
deleted_date TEXT,
apparat_id_adis INTEGER,
prof_id_adis INTEGER,
konto INTEGER,
FOREIGN KEY (prof_id) REFERENCES prof (id)
);
CREATE TABLE IF NOT EXISTS media (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
bookdata TEXT,
app_id INTEGER,
prof_id INTEGER,
deleted INTEGER DEFAULT (0),
available BOOLEAN,
reservation BOOLEAN,
FOREIGN KEY (prof_id) REFERENCES prof (id),
FOREIGN KEY (app_id) REFERENCES semesterapparat (id)
);
CREATE TABLE IF NOT EXISTS files (
id INTEGER PRIMARY KEY,
filename TEXT,
fileblob BLOB,
app_id INTEGER,
filetyp TEXT,
prof_id INTEGER REFERENCES prof (id),
FOREIGN KEY (app_id) REFERENCES semesterapparat (id)
);
CREATE TABLE IF NOT EXISTS messages (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
created_at date NOT NULL DEFAULT CURRENT_TIMESTAMP,
message TEXT NOT NULL,
remind_at date NOT NULL DEFAULT CURRENT_TIMESTAMP,
user_id INTEGER NOT NULL,
appnr INTEGER,
FOREIGN KEY (user_id) REFERENCES user (id)
);
CREATE TABLE IF NOT EXISTS prof (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
titel TEXT,
fname TEXT,
lname TEXT,
fullname TEXT NOT NULL UNIQUE,
mail TEXT,
telnr TEXT
);
CREATE TABLE IF NOT EXISTS user (
id integer NOT NULL PRIMARY KEY AUTOINCREMENT,
created_at datetime NOT NULL DEFAULT CURRENT_TIMESTAMP,
username TEXT NOT NULL UNIQUE,
password TEXT NOT NULL,
salt TEXT NOT NULL,
role TEXT NOT NULL,
email TEXT UNIQUE,
name TEXT
);
CREATE TABLE IF NOT EXISTS subjects (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
name TEXT NOT NULL UNIQUE
);
CREATE TABLE IF NOT EXISTS elsa (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
date TEXT NOT NULL,
semester TEXT NOT NULL,
prof_id INTEGER NOT NULL
);
CREATE TABLE IF NOT EXISTS elsa_files (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
filename TEXT NOT NULL,
fileblob BLOB NOT NULL,
elsa_id INTEGER NOT NULL,
filetyp TEXT NOT NULL,
FOREIGN KEY (elsa_id) REFERENCES elsa (id)
);
CREATE TABLE IF NOT EXISTS elsa_media (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
work_author TEXT,
section_author TEXT,
year TEXT,
edition TEXT,
work_title TEXT,
chapter_title TEXT,
location TEXT,
publisher TEXT,
signature TEXT,
issue TEXT,
pages TEXT,
isbn TEXT,
type TEXT,
elsa_id INTEGER NOT NULL,
FOREIGN KEY (elsa_id) REFERENCES elsa (id)
);
CREATE TABLE IF NOT EXISTS neweditions (
id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
new_bookdata TEXT,
old_edition_id INTEGER,
for_apparat INTEGER,
ordered BOOLEAN DEFAULT (0),
FOREIGN KEY (old_edition_id) REFERENCES media (id),
FOREIGN KEY (for_apparat) REFERENCES semesterapparat (id)
);
-- Helpful indices to speed up frequent lookups and joins
CREATE INDEX IF NOT EXISTS idx_media_app_prof ON media(app_id, prof_id);
CREATE INDEX IF NOT EXISTS idx_media_deleted ON media(deleted);
CREATE INDEX IF NOT EXISTS idx_media_available ON media(available);
CREATE INDEX IF NOT EXISTS idx_messages_remind_at ON messages(remind_at);
CREATE INDEX IF NOT EXISTS idx_semesterapparat_prof ON semesterapparat(prof_id);
CREATE INDEX IF NOT EXISTS idx_semesterapparat_appnr ON semesterapparat(appnr);
COMMIT;