CREATE TABLE schoolyears (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    name VARCHAR NOT NULL,
    start_date DATE NOT NULL,
    end_date DATE NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE tenants (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    active BOOLEAN NOT NULL DEFAULT FALSE,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE UNIQUE INDEX tenants_active ON tenants (active)
WHERE
    active;

CREATE TABLE teachers (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    forename VARCHAR,
    display_name VARCHAR NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE classes (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    long_name VARCHAR NOT NULL,
    active BOOLEAN NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE subjects (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    long_name VARCHAR NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE rooms (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    long_name VARCHAR NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE departments (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    long_name VARCHAR NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE holidays (
    id SERIAL PRIMARY KEY,
    untis_id INTEGER NOT NULL UNIQUE,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    name VARCHAR NOT NULL,
    long_name VARCHAR NOT NULL,
    start_date DATE NOT NULL,
    end_date DATE NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE timegrids (
    id SERIAL PRIMARY KEY,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE timegrid_days (
    id SERIAL PRIMARY KEY,
    timegrid_id INTEGER NOT NULL REFERENCES timegrids (id),
    day_index SMALLINT NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE timegrid_time_unit (
    id SERIAL PRIMARY KEY,
    timegrid_day_id INTEGER NOT NULL REFERENCES timegrid_days (id),
    start_time TIME NOT NULL,
    end_time TIME NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TYPE week_type AS ENUM ('a', 'b');

CREATE TABLE substitution_queries (
    id SERIAL PRIMARY KEY,
    schoolyear_id INTEGER NOT NULL REFERENCES schoolyears (id),
    date DATE NOT NULL,
    week_type week_type NOT NULL,
    queried_at TIMESTAMP NOT NULL,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TYPE substitution_type AS ENUM (
    'cancel',
    'subst',
    'add',
    'shift',
    'rmchg',
    'rmlk',
    'bs',
    'oh',
    'sb',
    'other',
    'free',
    'exam',
    'ac',
    'holi',
    'stxt'
);

CREATE TABLE substitutions(
    id SERIAL PRIMARY KEY,
    substitution_query_id INTEGER NOT NULL REFERENCES substitution_queries (id),
    subst_type substitution_type NOT NULL,
    lesson_id INTEGER NOT NULL,
    start_time TIME NOT NULL,
    end_time TIME NOT NULL,
    text VARCHAR,
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE substitution_classes (
    id SERIAL PRIMARY KEY,
    substitution_id INTEGER NOT NULL REFERENCES substitutions (id),
    position SMALLINT NOT NULL,
    class_id INTEGER NOT NULL REFERENCES classes (id),
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE substitution_teachers (
    id SERIAL PRIMARY KEY,
    substitution_id INTEGER NOT NULL REFERENCES substitutions (id),
    position SMALLINT NOT NULL,
    teacher_id INTEGER REFERENCES teachers (id),
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE substitution_subjects (
    id SERIAL PRIMARY KEY,
    substitution_id INTEGER NOT NULL REFERENCES substitutions (id),
    position SMALLINT NOT NULL,
    subject_id INTEGER NOT NULL REFERENCES subjects (id),
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);

CREATE TABLE substitution_rooms (
    id SERIAL PRIMARY KEY,
    substitution_id INTEGER NOT NULL REFERENCES substitutions (id),
    position SMALLINT NOT NULL,
    room_id INTEGER REFERENCES rooms (id),
    original_room_id INTEGER REFERENCES rooms (id),
    created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP
);