sascha@2823: BEGIN;
sascha@2823: 
sascha@2823: CREATE SEQUENCE LOCATION_SYSTEM_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE location_system (
mschaefer@8965:     id          int NOT NULL,
sascha@2823:     name        VARCHAR(32)  NOT NULL,
sascha@2823:     description VARCHAR(255),
sascha@2823:     PRIMARY KEY(id)
sascha@2823: );
sascha@2823: 
sascha@2823: 
sascha@2823: CREATE SEQUENCE ELEVATION_MODEL_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE elevation_model (
mschaefer@8965:     id          int NOT NULL,
sascha@2823:     name        VARCHAR(32)  NOT NULL,
mschaefer@8965:     unit_id     int NOT NULL,
sascha@2823:     PRIMARY KEY(id),
sascha@2823:     CONSTRAINT fk_unit FOREIGN KEY (unit_id) REFERENCES units(id)
sascha@2823: );
sascha@2823: 
sascha@2823: 
tom@5202: -- lookup table for bedheight types
sascha@2823: CREATE TABLE bed_height_type (
mschaefer@8965:     id          int NOT NULL,
teichmann@5273:     name        VARCHAR(64) NOT NULL,
sascha@2823:     PRIMARY KEY(id)
sascha@2823: );
tom@5276: INSERT INTO bed_height_type VALUES (1, 'Querprofile');
tom@5275: INSERT INTO bed_height_type VALUES (2, 'Flächenpeilung');
tom@5275: INSERT INTO bed_height_type VALUES (3, 'Flächen- u. Querprofilpeilungen');
tom@5275: INSERT INTO bed_height_type VALUES (4, 'DGM');
tom@5275: INSERT INTO bed_height_type VALUES (5, 'TIN');
tom@5275: INSERT INTO bed_height_type VALUES (6, 'Modell');
sascha@2823: 
sascha@2823: 
tom@8559: CREATE SEQUENCE BED_HEIGHT_ID_SEQ;
sascha@2823: 
tom@8559: CREATE TABLE bed_height (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     river_id                int NOT NULL,
mschaefer@8965:     year                    int,
mschaefer@8965:     type_id                 int NOT NULL,
mschaefer@8965:     location_system_id      int NOT NULL,
mschaefer@8965:     cur_elevation_model_id  int NOT NULL,
mschaefer@8965:     old_elevation_model_id  int,
mschaefer@8965:     range_id                int,
sascha@2823:     evaluation_by           VARCHAR(255),
sascha@2823:     description             VARCHAR(255),
sascha@2823:     PRIMARY KEY(id),
tom@8666:     CONSTRAINT fk_bh_river_id FOREIGN KEY (river_id)
tom@8559:         REFERENCES rivers(id) ON DELETE CASCADE,
tom@8666:     CONSTRAINT fk_bh_type FOREIGN KEY (type_id) REFERENCES bed_height_type(id),
tom@8666:     CONSTRAINT fk_bh_location_system FOREIGN KEY (location_system_id)
tom@8559:         REFERENCES location_system(id),
tom@8666:     CONSTRAINT fk_bh_cur_elevation_model FOREIGN KEY (cur_elevation_model_id)
tom@8559:         REFERENCES elevation_model(id),
tom@8666:     CONSTRAINT fk_bh_old_elevation_model FOREIGN KEY (old_elevation_model_id)
tom@8559:         REFERENCES elevation_model(id),
tom@8666:     CONSTRAINT fk_bh_range FOREIGN KEY (range_id)
tom@8559:         REFERENCES ranges(id) ON DELETE CASCADE
sascha@2823: );
sascha@2823: 
sascha@2823: 
tom@8559: CREATE SEQUENCE BED_HEIGHT_VALUES_ID_SEQ;
sascha@2823: 
tom@8559: CREATE TABLE bed_height_values (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     bed_height_id    int NOT NULL,
mschaefer@8965:     station                 NUMERIC NOT NULL,
mschaefer@8965:     height                  NUMERIC,
mschaefer@8965:     uncertainty             NUMERIC,
mschaefer@8965:     data_gap                NUMERIC,
mschaefer@8965:     sounding_width          NUMERIC,
sascha@2823:     PRIMARY KEY(id),
tom@8559:     UNIQUE (station, bed_height_id),
tom@8559:     CONSTRAINT fk_bed_values_parent FOREIGN KEY (bed_height_id)
tom@8559:         REFERENCES bed_height(id) ON DELETE CASCADE
sascha@2823: );
sascha@2823: 
sascha@2823: 
sascha@2823: CREATE SEQUENCE DEPTHS_ID_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE depths (
mschaefer@8965:     id      int NOT NULL,
mschaefer@8965:     lower   NUMERIC NOT NULL,
mschaefer@8965:     upper   NUMERIC NOT NULL,
tom@5441:     PRIMARY KEY(id)
sascha@2823: );
sascha@2823: 
sascha@2823: 
sascha@2823: CREATE SEQUENCE SEDIMENT_DENSITY_ID_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE sediment_density (
mschaefer@8965:     id          int NOT NULL,
mschaefer@8965:     river_id    int NOT NULL,
mschaefer@8965:     depth_id    int NOT NULL,
sascha@2823:     description VARCHAR(256),
sascha@2823:     PRIMARY KEY(id),
tom@4991:     CONSTRAINT fk_sd_river_id FOREIGN KEY (river_id) REFERENCES rivers(id) ON DELETE CASCADE,
tom@5441:     CONSTRAINT fk_sd_depth_id FOREIGN KEY (depth_id) REFERENCES depths(id)
sascha@2823: );
sascha@2823: 
sascha@2823: 
sascha@2823: CREATE SEQUENCE SEDIMENT_DENSITY_VALUES_ID_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE sediment_density_values (
mschaefer@8965:     id                  int NOT NULL,
mschaefer@8965:     sediment_density_id int NOT NULL,
mschaefer@8965:     station             NUMERIC NOT NULL,
mschaefer@8965:     shore_offset	NUMERIC,
mschaefer@8965:     density             NUMERIC NOT NULL,
sascha@2823:     description         VARCHAR(256),
mschaefer@8965:     year                int,
sascha@2823:     PRIMARY KEY(id),
tom@4991:     CONSTRAINT fk_sdv_sediment_density_id FOREIGN KEY(sediment_density_id) REFERENCES sediment_density(id) ON DELETE CASCADE
sascha@2823: );
sascha@2823: 
sascha@2823: 
rrenkert@7839: CREATE SEQUENCE POROSITY_ID_SEQ;
rrenkert@7839: 
rrenkert@7839: CREATE TABLE porosity (
mschaefer@8965:     id               int NOT NULL,
mschaefer@8965:     river_id         int NOT NULL,
mschaefer@8965:     depth_id         int NOT NULL,
rrenkert@7839:     description      VARCHAR(256),
mschaefer@8965:     time_interval_id int NOT NULL,
rrenkert@7839:     PRIMARY KEY(id),
rrenkert@7839:     CONSTRAINT fk_p_river_id FOREIGN KEY (river_id) REFERENCES rivers(id) ON DELETE CASCADE,
rrenkert@7839:     CONSTRAINT fk_p_depth_id FOREIGN KEY (depth_id) REFERENCES depths(id),
rrenkert@7839:     CONSTRAINT fk_p_time_interval_id FOREIGN KEY (time_interval_id) REFERENCES time_intervals(id)
rrenkert@7839: );
rrenkert@7839: 
rrenkert@7839: 
rrenkert@7839: CREATE SEQUENCE POROSITY_VALUES_ID_SEQ;
rrenkert@7839: 
rrenkert@7839: CREATE TABLE porosity_values (
mschaefer@8965:     id                  int NOT NULL,
mschaefer@8965:     porosity_id         int NOT NULL,
mschaefer@8965:     station             NUMERIC NOT NULL,
mschaefer@8965:     shore_offset        NUMERIC,
mschaefer@8965:     porosity            NUMERIC NOT NULL,
rrenkert@7839:     description         VARCHAR(256),
rrenkert@7839:     PRIMARY KEY(id),
rrenkert@7839:     CONSTRAINT fk_pv_porosity_id FOREIGN KEY(porosity_id) REFERENCES porosity(id) ON DELETE CASCADE
rrenkert@7839: );
rrenkert@7839: 
rrenkert@7839: 
sascha@2823: CREATE SEQUENCE MORPHOLOGIC_WIDTH_ID_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE morphologic_width (
mschaefer@8965:     id          int NOT NULL,
mschaefer@8965:     river_id    int NOT NULL,
mschaefer@8965:     unit_id     int NOT NULL,
sascha@2823:     PRIMARY KEY(id),
tom@4991:     CONSTRAINT fk_mw_river_id FOREIGN KEY(river_id) REFERENCES rivers(id) ON DELETE CASCADE,
sascha@2823:     CONSTRAINT fk_mw_unit_id FOREIGN KEY(unit_id) REFERENCES units(id)
sascha@2823: );
sascha@2823: 
sascha@2823: 
sascha@2823: CREATE SEQUENCE MORPH_WIDTH_VALUES_ID_SEQ;
sascha@2823: 
sascha@2823: CREATE TABLE morphologic_width_values (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     morphologic_width_id    int NOT NULL,
mschaefer@8965:     station                 NUMERIC NOT NULL,
mschaefer@8965:     width                   NUMERIC NOT NULL,
sascha@2823:     description             VARCHAR(256),
sascha@2823:     PRIMARY KEY(id),
tom@4991:     CONSTRAINT fk_mwv_morphologic_width_id FOREIGN KEY (morphologic_width_id) REFERENCES morphologic_width(id) ON DELETE CASCADE
sascha@2823: );
sascha@2823: 
sascha@2858: 
sascha@2858: CREATE SEQUENCE DISCHARGE_ZONE_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE discharge_zone (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     river_id                int NOT NULL,
sascha@2858:     gauge_name              VARCHAR(64)  NOT NULL, -- this is not very proper, but there are gauges with no db instance
mschaefer@8965:     value                   NUMERIC NOT NULL,
tom@6369:     lower_discharge         VARCHAR(64)  NOT NULL,
tom@6369:     upper_discharge         VARCHAR(64),
sascha@2858:     PRIMARY KEY(id),
tom@4991:     CONSTRAINT fk_dz_river_id FOREIGN KEY (river_id) REFERENCES rivers(id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: 
sascha@2858: CREATE SEQUENCE FLOW_VELOCITY_MODEL_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE flow_velocity_model (
mschaefer@8965:     id                  int NOT NULL,
mschaefer@8965:     discharge_zone_id   int NOT NULL,
sascha@2858:     description         VARCHAR(256),
sascha@2858:     PRIMARY KEY (id),
tom@4991:     CONSTRAINT fk_fvm_discharge_zone_id FOREIGN KEY (discharge_zone_id) REFERENCES discharge_zone (id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: 
sascha@2858: CREATE SEQUENCE FLOW_VELOCITY_M_VALUES_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE flow_velocity_model_values (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     flow_velocity_model_id  int NOT NULL,
mschaefer@8965:     station                 NUMERIC NOT NULL,
mschaefer@8965:     q                       NUMERIC NOT NULL,
mschaefer@8965:     total_channel           NUMERIC NOT NULL,
mschaefer@8965:     main_channel            NUMERIC NOT NULL,
mschaefer@8965:     shear_stress            NUMERIC NOT NULL,
sascha@2858:     PRIMARY KEY(id),
tom@5709:     UNIQUE (station, flow_velocity_model_id),
tom@4991:     CONSTRAINT fk_fvv_flow_velocity_model_id FOREIGN KEY (flow_velocity_model_id) REFERENCES flow_velocity_model(id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: 
sascha@2858: 
sascha@2858: CREATE SEQUENCE FV_MEASURE_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE flow_velocity_measurements (
mschaefer@8965:     id          int NOT NULL,
mschaefer@8965:     river_id    int NOT NULL,
sascha@2858:     description VARCHAR(256),
sascha@2858:     PRIMARY KEY (id),
tom@4991:     CONSTRAINT fk_fvm_rivers_id FOREIGN KEY (river_id) REFERENCES rivers(id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: CREATE SEQUENCE FV_MEASURE_VALUES_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE flow_velocity_measure_values (
mschaefer@8965:     id              int NOT NULL,
mschaefer@8965:     measurements_id int NOT NULL,
mschaefer@8965:     station         NUMERIC NOT NULL,
mschaefer@8965:     datetime        TIMESTAMP,
mschaefer@8965:     w               NUMERIC NOT NULL,
mschaefer@8965:     q               NUMERIC NOT NULL,
mschaefer@8965:     v               NUMERIC NOT NULL,
sascha@2858:     description     VARCHAR(256),
sascha@2858:     PRIMARY KEY (id),
tom@4991:     CONSTRAINT fk_fvmv_measurements_id FOREIGN KEY (measurements_id) REFERENCES flow_velocity_measurements (id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: 
sascha@2858: CREATE SEQUENCE GRAIN_FRACTION_ID_SEQ;
sascha@2858: 
sascha@2858: CREATE TABLE grain_fraction (
mschaefer@8965:     id      int   NOT NULL,
sascha@2858:     name    VARCHAR(64)    NOT NULL,
mschaefer@8965:     lower   NUMERIC,
mschaefer@8965:     upper   NUMERIC,
tom@8032:     PRIMARY KEY (id),
tom@8032:     UNIQUE(name, lower, upper)
sascha@2858: );
tom@8032: -- single fractions
tom@8032: INSERT INTO grain_fraction VALUES (1, 'coarse', 16, 200);
tom@8032: INSERT INTO grain_fraction VALUES (2, 'fine_middle', 2, 16);
tom@8032: INSERT INTO grain_fraction VALUES (3, 'sand', 0.063, 2);
tom@8032: INSERT INTO grain_fraction VALUES (4, 'susp_sand', 0.063, 2);
tom@8032: INSERT INTO grain_fraction VALUES (5, 'susp_sand_bed', 0.063, 2);
tom@8032: INSERT INTO grain_fraction VALUES (6, 'suspended_sediment', 0, 0.063);
tom@8032: -- aggregations of fractions
tom@8032: INSERT INTO grain_fraction VALUES (7, 'total', 0, 200);
tom@8032: INSERT INTO grain_fraction VALUES (8, 'bed_load', 0.063, 200);
tom@8032: INSERT INTO grain_fraction VALUES (9, 'suspended_load', 0, 2);
sascha@2858: 
mschaefer@8965: ALTER SEQUENCE GRAIN_FRACTION_ID_SEQ RESTART WITH 10;
mschaefer@8965: 
sascha@2858: 
tom@8072: --lookup table for sediment load kinds
tom@8072: CREATE TABLE sediment_load_kinds (
mschaefer@8965:     id 	     int PRIMARY KEY NOT NULL,
tom@7461:     kind     VARCHAR(64) NOT NULL
tom@7461: );
tom@8072: INSERT INTO sediment_load_kinds (id, kind) VALUES (0, 'non-official');
tom@8072: INSERT INTO sediment_load_kinds (id, kind) VALUES (1, 'official');
tom@7461: 
mschaefer@8965: 
tom@8072: CREATE SEQUENCE SEDIMENT_LOAD_LS_ID_SEQ;
sascha@2858: 
tom@8072: CREATE TABLE sediment_load_ls (
mschaefer@8965:     id                  int NOT NULL,
mschaefer@8965:     river_id            int NOT NULL,
mschaefer@8965:     grain_fraction_id   int,
mschaefer@8965:     unit_id             int NOT NULL,
mschaefer@8965:     time_interval_id    int NOT NULL,
mschaefer@8965:     sq_time_interval_id int,
sascha@2858:     description         VARCHAR(256),
mschaefer@8965:     kind                int,
sascha@2858:     PRIMARY KEY (id),
tom@8072:     CONSTRAINT fk_slls_river_id FOREIGN KEY (river_id)
tom@8072:         REFERENCES rivers(id) ON DELETE CASCADE,
tom@8072:     CONSTRAINT fk_slls_kind_id FOREIGN KEY (kind)
tom@8072:         REFERENCES sediment_load_kinds(id),
tom@8072:     CONSTRAINT fk_slls_grain_fraction_id FOREIGN KEY (grain_fraction_id)
tom@8072:         REFERENCES grain_fraction(id),
tom@8072:     CONSTRAINT fk_slls_unit_id FOREIGN KEY (unit_id)
tom@8072:         REFERENCES units(id),
tom@8072:     CONSTRAINT fk_slls_time_interval_id FOREIGN KEY (time_interval_id)
tom@8072:         REFERENCES time_intervals(id),
tom@8072:     CONSTRAINT fk_slls_sq_time_interval_id FOREIGN KEY (sq_time_interval_id)
tom@8059:         REFERENCES time_intervals(id)
sascha@2858: );
sascha@2858: 
sascha@2858: 
tom@8072: CREATE SEQUENCE SEDIMENT_LOAD_LS_VALUES_ID_SEQ;
sascha@2858: 
tom@8072: CREATE TABLE sediment_load_ls_values (
mschaefer@8965:     id                  int NOT NULL,
mschaefer@8965:     sediment_load_ls_id   int NOT NULL,
mschaefer@8965:     station             NUMERIC NOT NULL,
mschaefer@8965:     value               NUMERIC NOT NULL,
sascha@2858:     PRIMARY KEY (id),
tom@8072:     CONSTRAINT fk_sllsv_sediment_load_ls_id FOREIGN KEY (sediment_load_ls_id)
tom@8072:         REFERENCES sediment_load_ls(id) ON DELETE CASCADE
sascha@2858: );
sascha@2858: 
sascha@2858: 
ingo@4193: CREATE SEQUENCE MEASUREMENT_STATION_ID_SEQ;
ingo@4193: CREATE TABLE measurement_station (
mschaefer@8965:     id                       int          NOT NULL,
mschaefer@8965:     range_id                 int          NOT NULL,
mschaefer@8965:     reference_gauge_id       int,
mschaefer@8965:     time_interval_id         int,
aheinecke@5206:     name                     VARCHAR(256) NOT NULL,
aheinecke@5206:     measurement_type         VARCHAR(64)  NOT NULL,
aheinecke@5206:     riverside                VARCHAR(16),
tom@5456:     -- store name of reference gauges here too, as not all are in gauges
tom@5453:     reference_gauge_name     VARCHAR(64),
aheinecke@5206:     operator                 VARCHAR(64),
tom@8415:     commentary               VARCHAR(512),
aheinecke@5206:     PRIMARY KEY (id),
tom@8642:     CHECK(measurement_type IN ('Geschiebe', 'Schwebstoff')),
tom@8412:     CONSTRAINT fk_ms_range_id FOREIGN KEY (range_id)
tom@8412:         REFERENCES ranges(id) ON DELETE CASCADE,
tom@8412:     CONSTRAINT fk_ms_reference_gauge_id FOREIGN KEY (reference_gauge_id)
tom@8412:         REFERENCES gauges(id) ON DELETE CASCADE,
tom@8412:     CONSTRAINT fk_time_interval_id FOREIGN KEY (time_interval_id)
tom@8412:         REFERENCES time_intervals(id)
ingo@4193: );
ingo@4193: 
ingo@4193: 
tom@8017: CREATE SEQUENCE SEDIMENT_LOAD_ID_SEQ;
tom@8017: 
tom@8018: CREATE TABLE sediment_load (
mschaefer@8965:     id                    int NOT NULL,
mschaefer@8965:     grain_fraction_id     int NOT NULL,
mschaefer@8965:     time_interval_id      int NOT NULL,
mschaefer@8965:     sq_time_interval_id   int,
tom@8017:     description           VARCHAR(256),
mschaefer@8965:     kind                  int,
tom@8017:     PRIMARY KEY (id),
tom@8017:     CONSTRAINT fk_sl_kind_id FOREIGN KEY (kind)
tom@8072:         REFERENCES sediment_load_kinds(id),
tom@8017:     CONSTRAINT fk_sl_grain_fraction_id FOREIGN KEY (grain_fraction_id)
tom@8017:         REFERENCES grain_fraction(id),
tom@8641:     CONSTRAINT fk_sl_time_interval_id FOREIGN KEY (time_interval_id)
tom@8017:         REFERENCES time_intervals(id),
tom@8017:     CONSTRAINT fk_sl_sq_time_interval_id FOREIGN KEY (sq_time_interval_id)
tom@8017:         REFERENCES time_intervals(id)
tom@8017: );
tom@8017: 
tom@8017: 
tom@8017: CREATE SEQUENCE SEDIMENT_LOAD_VALUES_ID_SEQ;
tom@8017: 
tom@8017: CREATE TABLE sediment_load_values (
mschaefer@8965:     id                      int NOT NULL,
mschaefer@8965:     sediment_load_id        int NOT NULL,
mschaefer@8965:     measurement_station_id  int NOT NULL,
tom@8017:     value                   DOUBLE PRECISION NOT NULL,
tom@8017:     PRIMARY KEY (id),
tom@8017:     CONSTRAINT fk_slv_sediment_load_id FOREIGN KEY (sediment_load_id)
tom@8019:         REFERENCES sediment_load(id) ON DELETE CASCADE,
tom@8017:     CONSTRAINT fk_slv_m_station_id FOREIGN KEY (measurement_station_id)
tom@8017:         REFERENCES measurement_station(id) ON DELETE CASCADE
tom@8017: );
tom@8017: 
tom@8017: 
sascha@3793: CREATE SEQUENCE SQ_RELATION_ID_SEQ;
sascha@3793: 
sascha@3793: CREATE TABLE sq_relation (
mschaefer@8965:     id               int NOT NULL,
mschaefer@8965:     time_interval_id int NOT NULL,
sascha@3793:     description      VARCHAR(256),
sascha@3793:     PRIMARY KEY (id),
tom@8412:     CONSTRAINT fk_sqr_tinterval_id FOREIGN KEY (time_interval_id)
tom@8412:         REFERENCES time_intervals(id)
sascha@3793: );
sascha@3793: 
sascha@3793: 
sascha@3793: CREATE SEQUENCE SQ_RELATION_VALUES_ID_SEQ;
sascha@3793: 
sascha@3793: CREATE TABLE sq_relation_value (
mschaefer@8965:     id                     int NOT NULL,
mschaefer@8965:     sq_relation_id         int NOT NULL,
mschaefer@8965:     measurement_station_id int NOT NULL,
tom@5455:     parameter              VARCHAR(1) NOT NULL,
mschaefer@8965:     a                      NUMERIC NOT NULL,
mschaefer@8965:     b                      NUMERIC NOT NULL,
mschaefer@8965:     qmax                   NUMERIC NOT NULL,
mschaefer@8965:     rsq                    NUMERIC,
mschaefer@8965:     ntot                   int,
mschaefer@8965:     noutl                  int,
mschaefer@8965:     cferguson              NUMERIC,
mschaefer@8965:     cduan                  NUMERIC,
sascha@3793:     PRIMARY KEY (id),
tom@8691:     UNIQUE(sq_relation_id, measurement_station_id, parameter),
tom@8412:     CONSTRAINT fk_sqr_id FOREIGN KEY (sq_relation_id)
tom@8412:         REFERENCES sq_relation(id) ON DELETE CASCADE,
tom@8412:     CONSTRAINT fk_mstation_id FOREIGN KEY (measurement_station_id)
tom@8412:         REFERENCES measurement_station(id) ON DELETE CASCADE
sascha@3793: );
sascha@2823: COMMIT;