xmet/db/xmet.sql

177 lines
6 KiB
SQL

select load_extension('mod_spatialite.so.8');
select InitSpatialMetadata(1);
begin transaction;
create table xmet_wfo (
code TEXT PRIMARY KEY NOT NULL,
city TEXT NOT NULL,
state TEXT NOT NULL,
address TEXT NOT NULL
);
select
AddGeometryColumn('xmet_wfo', 'location', 4326, 'POINT', 'XY', 1),
CreateSpatialIndex('xmet_wfo', 'location');
create table xmet_nexrad_radar (
call TEXT PRIMARY KEY NOT NULL,
name TEXT NOT NULL,
wban INTEGER,
site_elevation FLOAT NOT NULL,
tower_height FLOAT NOT NULL
);
select
AddGeometryColumn('xmet_nexrad_radar', 'location', 4326, 'POINT', 'XY'),
CreateSpatialIndex('xmet_nexrad_radar', 'location');
create table xmet_storm_event (
id INTEGER PRIMARY KEY NOT NULL,
episode_id INTEGER,
timestamp_start TIMESTAMP NOT NULL,
timestamp_end TIMESTAMP NOT NULL,
state TEXT NOT NULL,
event_type TEXT NOT NULL,
wfo TEXT NOT NULL,
locale_start TEXT NOT NULL,
locale_end TEXT NOT NULL,
tornado_f_rating TEXT
);
create index xmet_storm_event_episode_id_idx on xmet_storm_event (episode_id);
create index xmet_storm_event_event_type_idx on xmet_storm_event (event_type);
create index xmet_storm_event_wfo_idx on xmet_storm_event (wfo);
create index xmet_storm_event_timestamp_start_idx on xmet_storm_event (timestamp_start);
create index xmet_storm_event_timestamp_end_idx on xmet_storm_event (timestamp_end);
select
AddGeometryColumn('xmet_storm_event', 'location_start', 4326, 'POINT', 'XY', 0),
CreateSpatialIndex('xmet_storm_event', 'location_start');
select
AddGeometryColumn('xmet_storm_event', 'location_end', 4326, 'POINT', 'XY', 0),
CreateSpatialIndex('xmet_storm_event', 'location_end');
create table xmet_afos_message (
id INTEGER PRIMARY KEY NOT NULL,
timestamp_issued TIMESTAMP NOT NULL,
serial INTEGER NOT NULL,
text_raw TEXT NOT NULL,
product TEXT NOT NULL,
wfo TEXT NOT NULL,
vtec_start TIMESTAMP,
vtec_end TIMESTAMP,
vtec_type TEXT,
actions TEXT,
phenom TEXT,
sig TEXT,
etn INTEGER,
hydro_severity TEXT,
hydro_cause TEXT,
hydro_record TEXT,
azimuth FLOAT,
speed FLOAT,
forecaster TEXT NOT NULL
);
create index xmet_afos_message_timestamp_idx on xmet_afos_message (timestamp_issued);
create index xmet_afos_message_vtec_timestamp_idx on xmet_afos_message (vtec_start, vtec_end);
create index xmet_afos_message_product_idx on xmet_afos_message (product);
create index xmet_afos_message_wfo_idx on xmet_afos_message (wfo);
create index xmet_afos_message_phenom_idx on xmet_afos_message (phenom);
create index xmet_afos_message_sig_idx on xmet_afos_message (sig);
select
AddGeometryColumn('xmet_afos_message', 'location', 4326, 'POINT'),
CreateSpatialIndex('xmet_afos_message', 'location');
select
AddGeometryColumn('xmet_afos_message', 'poly', 4326, 'POLYGON'),
CreateSpatialIndex('xmet_afos_message', 'poly');
create table xmet_igra_station (
code TEXT PRIMARY KEY NOT NULL,
year_start INTEGER NOT NULL,
year_end INTEGER NOT NULL,
name TEXT NOT NULL,
state TEXT,
elevation FLOAT NOT NULL
);
select
AddGeometryColumn('xmet_igra_station', 'location', 4326, 'POINT', 1),
CreateSpatialIndex('xmet_igra_station', 'location');
create table xmet_sounding (
id INTEGER PRIMARY KEY NOT NULL,
station TEXT NOT NULL,
timestamp_observed TIMESTAMP NOT NULL,
timestamp_released TIMESTAMP,
data_source_pressure TEXT NOT NULL,
data_source_other TEXT NOT NULL
);
create index xmet_sounding_station_idx on xmet_sounding (station);
create index xmet_sounding_timestamp_observed_idx on xmet_sounding (timestamp_observed);
create index xmet_sounding_timestamp_released_idx on xmet_sounding (timestamp_released);
create index xmet_sounding_timestamp_observed_released_idx on xmet_sounding (timestamp_observed, timestamp_released);
select AddGeometryColumn('xmet_sounding', 'location', 4326, 'POINT'),
CreateSpatialIndex('xmet_sounding', 'location');
create table xmet_sounding_sample (
id INTEGER PRIMARY KEY NOT NULL,
sounding_id INTEGER NOT NULL,
elapsed INTEGER,
pressure FLOAT,
pressure_qa TEXT NOT NULL,
height FLOAT,
height_qa TEXT NOT NULL,
temp FLOAT,
temp_qa TEXT NOT NULL,
humidity FLOAT,
dewpoint FLOAT,
wind_dir FLOAT,
wind_speed FLOAT,
FOREIGN KEY (sounding_id) REFERENCES xmet_sounding (id)
);
create index xmet_sounding_sample_sounding_id_idx on xmet_sounding_sample (sounding_id);
create table xmet_spc_outlook (
id INTEGER PRIMARY KEY NOT NULL,
timestamp_issued TIMESTAMP NOT NULL,
timestamp_start TIMESTAMP NOT NULL,
timestamp_end TIMESTAMP NOT NULL,
day INTEGER NOT NULL,
text_raw TEXT NOT NULL,
body TEXT NOT NULL
);
create table xmet_spc_outlook_probability_area (
id INTEGER PRIMARY KEY NOT NULL,
outlook_id INTEGER NOT NULL,
hazard TEXT NOT NULL,
probability FLOAT,
sig BOOLEAN NOT NULL DEFAULT FALSE,
FOREIGN KEY (outlook_id) REFERENCES xmet_spc_outlook (id)
);
select AddGeometryColumn('xmet_spc_outlook_probability_area', 'poly', 4326, 'POLYGON'),
CreateSpatialIndex('xmet_spc_outlook_probability_area', 'poly');
create table xmet_spc_outlook_category_area (
id INTEGER PRIMARY KEY NOT NULL,
outlook_id INTEGER NOT NULL,
category TEXT NOT NULL,
FOREIGN KEY (outlook_id) REFERENCES xmet_spc_outlook (id)
);
select AddGeometryColumn('xmet_spc_outlook_category_area', 'poly', 4326, 'POLYGON'),
CreateSpatialIndex('xmet_spc_outlook_category_area', 'poly');
commit;