DROP SCHEMA darwindb CASCADE;
CREATE SCHEMA darwindb;
SET search_path TO darwindb;

CREATE TABLE train_services (
    id BIGSERIAL NOT NULL PRIMARY KEY,
    rid VARCHAR(16) NOT NULL UNIQUE,
    uid VARCHAR(6) NOT NULL,
    rsid VARCHAR(8) NOT NULL,
    headcode VARCHAR(4) NOT NULL,
    scheduled_start_date DATE NOT NULL,
    effective_start_time TIMESTAMPTZ NULL, /* computed for ease of use */

    train_operator VARCHAR(2) NOT NULL,
    status VARCHAR(2) NOT NULL DEFAULT 'P',
    train_category VARCHAR(2) NOT NULL DEFAULT 'OO',
    is_passenger_svc BOOLEAN NOT NULL DEFAULT TRUE,
    is_charter BOOLEAN NOT NULL DEFAULT FALSE,
    is_q_train BOOLEAN NOT NULL DEFAULT FALSE,

    delay_reason_code VARCHAR NULL,
    delay_reason_tiploc VARCHAR NULL,
    delay_reason_tiploc_near BOOLEAN NULL, 

    cancellation_reason_code VARCHAR NULL,
    cancellation_reason_tiploc VARCHAR NULL,
    cancellation_reason_tiploc_near BOOLEAN NULL, 

    active BOOLEAN NOT NULL DEFAULT TRUE,
    deleted BOOLEAN NOT NULL DEFAULT FALSE,
    cancelled BOOLEAN NOT NULL DEFAULT FALSE
);

CREATE INDEX train_services_by_ssd_uid ON train_services (scheduled_start_date, uid);
CREATE INDEX train_services_by_ssd_rsid ON train_services (scheduled_start_date, rsid);
CREATE INDEX train_services_by_ssd_headcode ON train_services (scheduled_start_date, headcode);

CREATE TYPE timestamp_type AS ENUM ('est', 'act');
CREATE TYPE platform_source AS ENUM ('planned', 'automatic', 'manual');
CREATE TYPE calling_point_type AS ENUM ('OR', 'OPOR', 'IP', 'OPIP', 'PP', 'DT', 'OPDT');

CREATE TABLE train_locations (
    id BIGSERIAL NOT NULL PRIMARY KEY,
    tsid BIGINT NOT NULL REFERENCES train_services (id) ON DELETE CASCADE,
    rid VARCHAR(16) NOT NULL REFERENCES train_services (rid) ON DELETE CASCADE,
    tiploc VARCHAR(7) NOT NULL,

    -- From Darwin Schedule
    calling_point calling_point_type NULL,
    schedule_public_arrival TIMESTAMPTZ NULL,
    schedule_working_arrival TIMESTAMPTZ NULL,
    schedule_public_departure TIMESTAMPTZ NULL,
    schedule_working_departure TIMESTAMPTZ NULL,
    -- No concept of a "public pass"
    schedule_working_pass TIMESTAMPTZ NULL,
    schedule_route_delay SMALLINT NULL,
    schedule_activity VARCHAR(12) NULL,
    schedule_planned_activity VARCHAR(12) NULL,
    schedule_cancelled BOOLEAN NOT NULL DEFAULT false,
    schedule_false_destination_tiploc VARCHAR(7) NULL,
    schedule_platform VARCHAR(5) NULL,

    -- Indicates whether this appeared in a schedule we've seen previously, but not in the latest version.
    active_in_schedule BOOLEAN NOT NULL DEFAULT true,

    -- From Darwin TrainStatus
    service_suppressed BOOLEAN NOT NULL DEFAULT false,
    platform VARCHAR(5) NULL,
    platform_suppressed BOOLEAN NOT NULL DEFAULT false,
    cis_platform_suppression BOOLEAN NOT NULL DEFAULT false,
    platform_source platform_source NOT NULL DEFAULT 'planned',
    platform_confirmed BOOLEAN NOT NULL DEFAULT false,
    train_length SMALLINT NULL,

    -- estimated, working, actual
    -- arrival, departure, pass
    estimated_arrival TIMESTAMPTZ NULL,
    working_estimated_arrival TIMESTAMPTZ NULL,
    actual_arrival TIMESTAMPTZ NULL,
    arrival_data JSONB NULL,

    estimated_departure TIMESTAMPTZ NULL,
    working_estimated_departure TIMESTAMPTZ NULL,
    actual_departure TIMESTAMPTZ NULL,
    departure_data JSONB NULL,

    estimated_pass TIMESTAMPTZ NULL,
    working_estimated_pass TIMESTAMPTZ NULL,
    actual_pass TIMESTAMPTZ NULL,
    pass_data JSONB NULL,

    CONSTRAINT train_locations_tiploc_wtd UNIQUE (tsid, tiploc, schedule_working_departure),
    CONSTRAINT train_locations_tiploc_ptd UNIQUE (tsid, tiploc, schedule_public_departure),
    CONSTRAINT train_locations_tiploc_wta UNIQUE (tsid, tiploc, schedule_working_arrival),
    CONSTRAINT train_locations_tiploc_pta UNIQUE (tsid, tiploc, schedule_public_arrival),
    CONSTRAINT train_locations_tiploc_wtp UNIQUE (tsid, tiploc, schedule_working_pass)
);

CREATE INDEX train_locations_by_tsid ON train_locations (tsid, tiploc);
CREATE INDEX train_locations_by_rid ON train_locations (rid, tiploc);

CREATE FUNCTION train_locations_upsert_from_schedule (
    p_tsid BIGINT,
    p_rid VARCHAR(16),
    p_tiploc VARCHAR(7),
    p_calling_point calling_point_type,
    p_schedule_public_arrival TIMESTAMPTZ,
    p_schedule_working_arrival TIMESTAMPTZ,
    p_schedule_public_departure TIMESTAMPTZ,
    p_schedule_working_departure TIMESTAMPTZ,
    p_schedule_working_pass TIMESTAMPTZ,
    p_schedule_route_delay SMALLINT,
    p_schedule_activity VARCHAR(12),
    p_schedule_planned_activity VARCHAR(12),
    p_schedule_cancelled BOOLEAN,
    p_schedule_false_destination_tiploc VARCHAR(7),
    p_schedule_platform VARCHAR(3)) RETURNS BIGINT AS
$$
-- There is one problem with this function, which is why it's not generic and using ON CONFLICT DO UPDATE:
-- if we notice that one particular constraint has caused a problem, so we do an update, and _that_ update causes a problem
-- then we're stuck; in this instance we'll just explode.
--
-- Imagine the following (unlikely) case:
-- Old schedule: (tsid, tiploc, wtd, ptd):
-- (1, "AAAAAA", 01:00, 01:00)
-- (1, "AAAAAA", 01:10, 01:10)
-- If we then try to update with a new schedule location (1, "AAAAAA", 01:00, 01:10), we cause a conflict.
BEGIN
    LOOP
        DECLARE v_locid BIGINT;
        DECLARE v_constraint_name TEXT;
        BEGIN
            INSERT INTO train_locations
            (tsid, rid, tiploc, calling_point,
             schedule_public_arrival, schedule_working_arrival,
             schedule_public_departure, schedule_working_departure,
             schedule_working_pass,
             schedule_route_delay, schedule_activity, schedule_planned_activity, schedule_cancelled,
             schedule_false_destination_tiploc, schedule_platform)
            VALUES
            (p_tsid, p_rid, p_tiploc, p_calling_point,
             p_schedule_public_arrival, p_schedule_working_arrival,
             p_schedule_public_departure, p_schedule_working_departure,
             p_schedule_working_pass,
             p_schedule_route_delay, p_schedule_activity, p_schedule_planned_activity, p_schedule_cancelled,
             p_schedule_false_destination_tiploc, p_schedule_platform)
            RETURNING id INTO v_locid;
            RETURN v_locid;
        EXCEPTION WHEN unique_violation THEN
            -- Work out which constraint caused this.
            GET STACKED DIAGNOSTICS v_constraint_name = CONSTRAINT_NAME;
            CASE v_constraint_name
                WHEN 'train_locations_tiploc_wtd' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        schedule_public_arrival=p_schedule_public_arrival, schedule_working_arrival=p_schedule_working_arrival,
                        schedule_public_departure=p_schedule_public_departure, /* wtd */
                        schedule_working_pass=p_schedule_working_pass,
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_working_departure=p_schedule_working_departure
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                WHEN 'train_locations_tiploc_ptd' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        schedule_public_arrival=p_schedule_public_arrival, schedule_working_arrival=p_schedule_working_arrival,
                        /* ptd */ schedule_working_departure=p_schedule_working_departure,
                        schedule_working_pass=p_schedule_working_pass,
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_public_departure=p_schedule_public_departure
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                WHEN 'train_locations_tiploc_wta' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        schedule_public_arrival=p_schedule_public_arrival, /* wta */
                        schedule_public_departure=p_schedule_public_departure, schedule_working_departure=p_schedule_working_departure,
                        schedule_working_pass=p_schedule_working_pass,
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_working_arrival=p_schedule_working_arrival
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                WHEN 'train_locations_tiploc_pta' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        /* pta */ schedule_working_arrival=p_schedule_working_arrival,
                        schedule_public_departure=p_schedule_public_departure, schedule_working_departure=p_schedule_working_departure,
                        schedule_working_pass=p_schedule_working_pass,
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_public_arrival=p_schedule_public_arrival
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                WHEN 'train_locations_tiploc_wtp' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        schedule_public_arrival=p_schedule_public_arrival, schedule_working_arrival=p_schedule_working_arrival,
                        schedule_public_departure=p_schedule_public_departure, schedule_working_departure=p_schedule_working_departure,
                        /* wtp */
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_working_pass=p_schedule_working_pass
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                WHEN 'train_locations_tiploc_wtd' THEN
                    UPDATE train_locations SET
                        calling_point=p_calling_point,
                        schedule_public_arrival=p_schedule_public_arrival, schedule_working_arrival=p_schedule_working_arrival,
                        schedule_public_departure=p_schedule_public_departure, schedule_working_departure=p_schedule_working_departure,
                        schedule_working_pass=p_schedule_working_pass,
                        schedule_route_delay=p_schedule_route_delay, schedule_activity=p_schedule_activity, schedule_planned_activity=p_schedule_planned_activity, schedule_cancelled=p_schedule_cancelled,
                        schedule_false_destination_tiploc=p_schedule_false_destination_tiploc, schedule_platform=p_schedule_platform,
                        active_in_schedule=true
                    WHERE
                        tsid=p_tsid AND tiploc=p_tiploc AND schedule_working_departure=p_schedule_working_departure
                    RETURNING id INTO v_locid;
                    IF found THEN RETURN v_locid; END IF;
                    -- We didn't find it? Try again.
                ELSE
                    RAISE;  -- don't know how to deal with this particular constraint.
            END CASE;
        END; 
    END LOOP;
END;
$$
LANGUAGE plpgsql;

CREATE TABLE train_alerts (
    id BIGSERIAL NOT NULL PRIMARY KEY,
    alert_id BIGINT NOT NULL,

    source VARCHAR(10) NOT NULL,
    alert_text TEXT NOT NULL,
    audience VARCHAR(15) NOT NULL,
    alert_type VARCHAR(15) NOT NULL,

    send_alert_by_sms BOOLEAN NOT NULL,
    send_alert_by_email BOOLEAN NOT NULL,
    send_alert_by_twitter BOOLEAN NOT NULL
);

CREATE TABLE train_alert_services (
    id BIGSERIAL NOT NULL PRIMARY KEY,
    ta_id BIGINT NOT NULL REFERENCES train_alerts (id) ON DELETE CASCADE,
    service_id BIGINT NOT NULL REFERENCES train_services (id) ON DELETE CASCADE,
    crs VARCHAR(3) NULL,

    CONSTRAINT train_alert_services_by_service_id_crs UNIQUE (service_id, crs, ta_id)
);

CREATE TABLE ref_tocs (
    toc VARCHAR(2) PRIMARY KEY NOT NULL,
    name VARCHAR(256) NOT NULL,
    url VARCHAR(512) NULL
);

CREATE TABLE ref_locations (
    tiploc VARCHAR(7) PRIMARY KEY NOT NULL,
    name VARCHAR(30) NULL,
    override_name VARCHAR(30) NULL,
    crs VARCHAR(3) NULL,
    toc VARCHAR(2) NULL
);

CREATE INDEX ref_locations_by_crs ON ref_locations (crs);

CREATE TABLE ref_cancel_reasons (
    code INT NOT NULL PRIMARY KEY,
    text VARCHAR(256) NOT NULL
);

CREATE TABLE ref_late_running_reasons (
    code INT NOT NULL PRIMARY KEY,
    text VARCHAR(256) NOT NULL
);

CREATE TABLE ref_via (
    id BIGSERIAL NOT NULL PRIMARY KEY,
    at_crs VARCHAR(3) NOT NULL,
    dest_tiploc VARCHAR(7) NOT NULL,
    loc1_tiploc VARCHAR(7) NOT NULL,
    loc2_tiploc VARCHAR(7) NOT NULL DEFAULT '',
    text VARCHAR(256) NOT NULL,

    CONSTRAINT ref_via_by_at_dest_loc1_loc2 UNIQUE (at_crs, dest_tiploc, loc1_tiploc, loc2_tiploc)
);

CREATE TABLE ref_cis (
    code VARCHAR(4) NOT NULL PRIMARY KEY,
    name VARCHAR(60) NOT NULL
);