123 lines
4.2 KiB
SQL
123 lines
4.2 KiB
SQL
CREATE TABLE IF NOT EXISTS "user" (
|
|
"id" integer NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
"name" text NOT NULL UNIQUE,
|
|
"pw" text,
|
|
"is_cox" boolean NOT NULL DEFAULT FALSE,
|
|
"is_admin" boolean NOT NULL DEFAULT FALSE,
|
|
"is_guest" boolean NOT NULL DEFAULT TRUE,
|
|
"is_tech" boolean NOT NULL DEFAULT FALSE,
|
|
"deleted" boolean NOT NULL DEFAULT FALSE,
|
|
"last_access" DATETIME,
|
|
"dob" text,
|
|
"weight" text,
|
|
"sex" text,
|
|
"dirty_thirty" text,
|
|
"dirty_dozen" text
|
|
);
|
|
|
|
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,
|
|
"skull" boolean default true NOT NULL, -- false => riemen
|
|
"external" boolean default false NOT NULL -- false => owned by different club
|
|
);
|
|
|
|
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
|
|
);
|