CREATE TABLE IF NOT EXISTS "user" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE, "pw" text, "deleted" boolean NOT NULL DEFAULT FALSE, "last_access" DATETIME, "dob" text, "weight" text, "sex" text, "dirty_thirty" text, "dirty_dozen" text, "member_since_date" text, "birthdate" text, "mail" text, "nickname" text, "notes" text, "phone" text, "address" text, "family_id" INTEGER REFERENCES family(id), "membership_pdf" BLOB, "user_token" TEXT NOT NULL DEFAULT (lower(hex(randomblob(16)))) ); CREATE TABLE IF NOT EXISTS "family" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT ); CREATE TABLE IF NOT EXISTS "role" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE, "cluster" text ); CREATE TABLE IF NOT EXISTS "user_role" ( "user_id" INTEGER NOT NULL REFERENCES user(id), "role_id" INTEGER NOT NULL REFERENCES role(id), CONSTRAINT unq UNIQUE (user_id, role_id) ); CREATE TABLE IF NOT EXISTS "trip_type" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE, "desc" text NOT NULL, "question" text NOT NULL, "icon" text NOT NULL ); CREATE TABLE IF NOT EXISTS "trip_details" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "planned_starting_time" text NOT NULL, "max_people" INTEGER NOT NULL, "day" TEXT NOT NULL, "allow_guests" boolean NOT NULL default false, "notes" TEXT, "always_show" boolean NOT NULL default false, "is_locked" boolean NOT NULL default false, "trip_type_id" INTEGER REFERENCES trip_type(id) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "planned_event" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL, "planned_amount_cox" INTEGER unsigned NOT NULL, "trip_details_id" INTEGER NOT NULL REFERENCES TRIP_details(id) ON DELETE CASCADE, "created_at" text NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "trip" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "cox_id" INTEGER NOT NULL REFERENCES user(id), "trip_details_id" INTEGER REFERENCES trip_details(id) ON DELETE CASCADE, "planned_event_id" INTEGER REFERENCES planned_event(id) ON DELETE CASCADE, "created_at" text NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT unq UNIQUE (cox_id, planned_event_id) -- allow cox to participate only once for each planned event ); CREATE TABLE IF NOT EXISTS "user_trip" ( "user_id" INTEGER REFERENCES user(id), "user_note" text, -- only shown if user_id = none "trip_details_id" INTEGER NOT NULL REFERENCES trip_details(id), "created_at" text NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "log" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "msg" text NOT NULL, "created_at" DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "location" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE ); CREATE TABLE IF NOT EXISTS "boat" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE, "amount_seats" integer NOT NULL, "location_id" INTEGER NOT NULL REFERENCES location(id) DEFAULT 1, "owner" INTEGER REFERENCES user(id), -- null: club is owner "year_built" INTEGER, "boatbuilder" TEXT, "default_shipmaster_only_steering" boolean default false not null, "convert_handoperated_possible" boolean default false not null, "default_destination" text, "skull" boolean default true NOT NULL, -- false => riemen "external" boolean default false NOT NULL, -- false => owned by different club "deleted" boolean NOT NULL DEFAULT FALSE ); CREATE TABLE IF NOT EXISTS "logbook_type" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE -- e.g. 'Wanderfahrt', 'Regatta' ); CREATE TABLE IF NOT EXISTS "logbook" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "boat_id" INTEGER NOT NULL REFERENCES boat(id), "shipmaster" INTEGER NOT NULL REFERENCES user(id), "steering_person" INTEGER NOT NULL REFERENCES user(id), "shipmaster_only_steering" boolean not null, "departure" datetime not null, "arrival" datetime, -- None -> ship is on water "destination" text, "distance_in_km" integer, "comments" text, "logtype" INTEGER REFERENCES logbook_type(id) ); CREATE TABLE IF NOT EXISTS "rower" ( "logbook_id" INTEGER NOT NULL REFERENCES logbook(id) ON DELETE CASCADE, "rower_id" INTEGER NOT NULL REFERENCES user(id), CONSTRAINT unq UNIQUE (logbook_id, rower_id) ); CREATE TABLE IF NOT EXISTS "boat_damage" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "boat_id" INTEGER NOT NULL REFERENCES boat(id), "desc" text not null, "user_id_created" INTEGER NOT NULL REFERENCES user(id), "created_at" datetime not null default CURRENT_TIMESTAMP, "user_id_fixed" INTEGER REFERENCES user(id), -- none: not fixed yet "fixed_at" datetime, "user_id_verified" INTEGER REFERENCES user(id), "verified_at" datetime, "lock_boat" boolean not null default false -- if true: noone can use the boat ); CREATE TABLE IF NOT EXISTS "boathouse" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT, "boat_id" INTEGER NOT NULL REFERENCES boat(id), "aisle" TEXT NOT NULL CHECK (aisle in ('water', 'middle', 'mountain')), "side" TEXT NOT NULL CHECK(side IN ('mountain', 'water')), "level" INTEGER NOT NULL CHECK(level BETWEEN 0 AND 11), CONSTRAINT unq UNIQUE (aisle, side, level) -- only 1 boat allowed to rest at each space ); CREATE TABLE IF NOT EXISTS "notification" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "user_id" INTEGER NOT NULL REFERENCES user(id), "message" TEXT NOT NULL, "read_at" DATETIME, "created_at" DATETIME DEFAULT CURRENT_TIMESTAMP NOT NULL, "category" TEXT NOT NULL, "action_after_reading" TEXT, "link" TEXT ); CREATE TABLE IF NOT EXISTS "boat_reservation" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "boat_id" INTEGER NOT NULL REFERENCES boat(id), "start_date" DATE NOT NULL, "end_date" DATE NOT NULL, "time_desc" TEXT NOT NULL, "usage" TEXT NOT NULL, "user_id_applicant" INTEGER NOT NULL REFERENCES user(id), "user_id_confirmation" INTEGER REFERENCES user(id), "created_at" datetime not null default CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "waterlevel" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "day" DATE NOT NULL, "time" TEXT NOT NULL, "max" INTEGER NOT NULL, "min" INTEGER NOT NULL, "mittel" INTEGER NOT NULL, "tumax" INTEGER NOT NULL, "tumin" INTEGER NOT NULL, "tumittel" INTEGER NOT NULL ); CREATE TABLE IF NOT EXISTS "weather" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "day" DATE NOT NULL, "max_temp" FLOAT NOT NULL, "wind_gust" FLOAT NOT NULL, "rain_mm" FLOAT NOT NULL ); CREATE TABLE IF NOT EXISTS "trailer" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "name" text NOT NULL UNIQUE ); CREATE TABLE IF NOT EXISTS "trailer_reservation" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "trailer_id" INTEGER NOT NULL REFERENCES trailer(id), "start_date" DATE NOT NULL, "end_date" DATE NOT NULL, "time_desc" TEXT NOT NULL, "usage" TEXT NOT NULL, "user_id_applicant" INTEGER NOT NULL REFERENCES user(id), "user_id_confirmation" INTEGER REFERENCES user(id), "created_at" datetime not null default CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS "distance" ( "id" integer NOT NULL PRIMARY KEY AUTOINCREMENT, "destination" text NOT NULL, "distance_in_km" integer NOT NULL ); CREATE UNIQUE INDEX one_role_per_group_per_user ON user_role WHERE EXISTS ( SELECT 1 FROM role r1 JOIN role r2 ON r1.id = user_role.role_id WHERE r1."group" = r2."group" AND r2.id IN ( SELECT role_id FROM user_role ur2 WHERE ur2.user_id = user_role.user_id ) );