init.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304
  1. SET statement_timeout = 0;
  2. SET lock_timeout = 0;
  3. SET idle_in_transaction_session_timeout = 0;
  4. SET client_encoding = 'UTF8';
  5. SET standard_conforming_strings = on;
  6. SELECT pg_catalog.set_config('search_path', '', false);
  7. SET check_function_bodies = false;
  8. SET xmloption = content;
  9. SET client_min_messages = warning;
  10. SET row_security = off;
  11. CREATE ROLE senslog NOSUPERUSER NOCREATEDB NOCREATEROLE INHERIT;
  12. CREATE ROLE maplog_app NOSUPERUSER NOCREATEDB NOCREATEROLE INHERIT LOGIN PASSWORD 'MAPlog';
  13. GRANT senslog TO maplog_app;
  14. CREATE DATABASE maplog WITH TEMPLATE = template0 ENCODING = 'UTF8' LOCALE_PROVIDER = 'libc' LOCALE = 'en_US.UTF-8';
  15. ALTER DATABASE maplog OWNER TO senslog;
  16. \connect maplog
  17. SET statement_timeout = 0;
  18. SET lock_timeout = 0;
  19. SET idle_in_transaction_session_timeout = 0;
  20. SET client_encoding = 'UTF8';
  21. SET standard_conforming_strings = on;
  22. SELECT pg_catalog.set_config('search_path', '', false);
  23. SET check_function_bodies = false;
  24. SET xmloption = content;
  25. SET client_min_messages = warning;
  26. SET row_security = off;
  27. CREATE SCHEMA maplog;
  28. ALTER SCHEMA maplog OWNER TO senslog;
  29. ALTER SCHEMA public OWNER TO senslog;
  30. CREATE EXTENSION IF NOT EXISTS postgis WITH SCHEMA public;
  31. COMMENT ON EXTENSION postgis IS 'PostGIS geometry and geography spatial types and functions';
  32. SET default_tablespace = '';
  33. CREATE TABLE maplog.campaign (
  34. id INTEGER NOT NULL PRIMARY KEY,
  35. name TEXT NOT NULL,
  36. description TEXT NOT NULL,
  37. from_time TIMESTAMP WITH TIME ZONE NOT NULL,
  38. to_time TIMESTAMP WITH TIME ZONE NOT NULL,
  39. CONSTRAINT campaign_check_time CHECK (from_time < to_time)
  40. );
  41. ALTER TABLE maplog.campaign OWNER TO senslog;
  42. CREATE SEQUENCE maplog.campaign_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  43. ALTER TABLE maplog.campaign_id_seq OWNER TO senslog;
  44. ALTER SEQUENCE maplog.campaign_id_seq OWNED BY maplog.campaign.id;
  45. ALTER TABLE ONLY maplog.campaign ALTER COLUMN id SET DEFAULT nextval('maplog.campaign_id_seq'::regclass);
  46. CREATE TABLE maplog.obs_telemetry (
  47. id BIGINT NOT NULL PRIMARY KEY,
  48. time_stamp TIMESTAMP WITH TIME ZONE NOT NULL,
  49. unit_id BIGINT NOT NULL,
  50. observed_values jsonb NOT NULL,
  51. the_geom public.geometry NOT NULL,
  52. speed INTEGER NOT NULL,
  53. time_received TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL
  54. );
  55. ALTER TABLE maplog.obs_telemetry OWNER TO senslog;
  56. CREATE SEQUENCE maplog.obs_telemetry_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  57. ALTER TABLE maplog.obs_telemetry_id_seq OWNER TO senslog;
  58. ALTER SEQUENCE maplog.obs_telemetry_id_seq OWNED BY maplog.obs_telemetry.id;
  59. ALTER TABLE ONLY maplog.obs_telemetry ALTER COLUMN id SET DEFAULT nextval('maplog.obs_telemetry_id_seq'::regclass);
  60. CREATE TABLE maplog.driver (
  61. driver_id INTEGER NOT NULL PRIMARY KEY,
  62. name VARCHAR(100) NOT NULL
  63. );
  64. ALTER TABLE maplog.driver OWNER TO senslog;
  65. CREATE TABLE maplog.action (
  66. action_id INTEGER NOT NULL PRIMARY KEY,
  67. name VARCHAR(100) NOT NULL
  68. );
  69. ALTER TABLE maplog.action OWNER TO senslog;
  70. CREATE TABLE maplog.driver_to_action ( -- rename to event --
  71. id BIGINT NOT NULL PRIMARY KEY,
  72. driver_id INTEGER NOT NULL,
  73. action_id INTEGER NOT NULL,
  74. unit_id BIGINT NOT NULL,
  75. from_time TIMESTAMP WITH TIME ZONE NOT NULL,
  76. to_time TIMESTAMP WITH TIME ZONE,
  77. CONSTRAINT dta_check_time CHECK (from_time < to_time)
  78. );
  79. ALTER TABLE maplog.driver_to_action OWNER TO senslog;
  80. CREATE SEQUENCE maplog.driver_to_action_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  81. ALTER TABLE maplog.driver_to_action_id_seq OWNER TO senslog;
  82. ALTER SEQUENCE maplog.driver_to_action_id_seq OWNED BY maplog.driver_to_action.id;
  83. ALTER TABLE ONLY maplog.driver_to_action ALTER COLUMN id SET DEFAULT nextval('maplog.driver_to_action_id_seq'::regclass);
  84. CREATE TABLE maplog.phenomenon (
  85. id INTEGER NOT NULL PRIMARY KEY,
  86. name TEXT NOT NULL,
  87. uom CHARACTER VARYING(30) NOT NULL,
  88. uom_link TEXT
  89. );
  90. ALTER TABLE maplog.phenomenon OWNER TO senslog;
  91. CREATE SEQUENCE maplog.phenomenon_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  92. ALTER TABLE maplog.phenomenon_id_seq OWNER TO senslog;
  93. ALTER SEQUENCE maplog.phenomenon_id_seq OWNED BY maplog.phenomenon.id;
  94. ALTER TABLE ONLY maplog.phenomenon ALTER COLUMN id SET DEFAULT nextval('maplog.phenomenon_id_seq'::regclass);
  95. INSERT INTO maplog.phenomenon(id, name, uom, uom_link) VALUES (0, 'GENERAL', 'UOM', null);
  96. CREATE TABLE maplog.sensor (
  97. sensor_id BIGINT NOT NULL PRIMARY KEY,
  98. name CHARACTER VARYING(100) UNIQUE NOT NULL,
  99. type TEXT,
  100. description TEXT,
  101. io_id INTEGER NOT NULL,
  102. phenomenon_id INTEGER NOT NULL
  103. );
  104. ALTER TABLE maplog.sensor OWNER TO senslog;
  105. CREATE SEQUENCE maplog.sensor_sensor_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  106. ALTER TABLE maplog.sensor_sensor_id_seq OWNER TO senslog;
  107. ALTER SEQUENCE maplog.sensor_sensor_id_seq OWNED BY maplog.sensor.sensor_id;
  108. ALTER TABLE ONLY maplog.sensor ALTER COLUMN sensor_id SET DEFAULT nextval('maplog.sensor_sensor_id_seq'::regclass);
  109. CREATE TABLE maplog.system_user (
  110. user_id INTEGER NOT NULL PRIMARY KEY,
  111. name TEXT NOT NULL
  112. );
  113. ALTER TABLE maplog.system_user OWNER TO senslog;
  114. INSERT INTO maplog.system_user(user_id, name) VALUES (0, 'admin');
  115. CREATE TABLE maplog.unit (
  116. unit_id BIGINT NOT NULL PRIMARY KEY,
  117. imei CHARACTER VARYING(20) NOT NULL UNIQUE,
  118. name CHARACTER VARYING(100) NOT NULL,
  119. description TEXT,
  120. is_mobile boolean DEFAULT true NOT NULL,
  121. unit_type_id CHARACTER VARYING(2) DEFAULT 'X'::CHARACTER VARYING NOT NULL
  122. );
  123. ALTER TABLE maplog.unit OWNER TO senslog;
  124. CREATE TABLE maplog.unit_to_campaign (
  125. id INTEGER NOT NULL PRIMARY KEY,
  126. campaign_id INTEGER NOT NULL,
  127. unit_id BIGINT NOT NULL,
  128. from_time TIMESTAMP WITH TIME ZONE NOT NULL,
  129. to_time TIMESTAMP WITH TIME ZONE NOT NULL
  130. );
  131. ALTER TABLE maplog.unit_to_campaign OWNER TO senslog;
  132. CREATE SEQUENCE maplog.unit_to_campaign_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  133. ALTER TABLE maplog.unit_to_campaign_id_seq OWNER TO senslog;
  134. ALTER SEQUENCE maplog.unit_to_campaign_id_seq OWNED BY maplog.unit_to_campaign.id;
  135. ALTER TABLE ONLY maplog.unit_to_campaign ALTER COLUMN id SET DEFAULT nextval('maplog.unit_to_campaign_id_seq'::regclass);
  136. CREATE TABLE maplog.unit_to_sensor (
  137. sensor_id BIGINT NOT NULL,
  138. unit_id BIGINT NOT NULL,
  139. PRIMARY KEY (unit_id, sensor_id)
  140. );
  141. ALTER TABLE maplog.unit_to_sensor OWNER TO senslog;
  142. CREATE TABLE maplog.unit_type (
  143. unit_type_id CHARACTER VARYING(2) NOT NULL PRIMARY KEY,
  144. name CHARACTER VARYING(20) NOT NULL,
  145. description TEXT
  146. );
  147. ALTER TABLE maplog.unit_type OWNER TO senslog;
  148. CREATE TABLE maplog.user_to_campaign (
  149. user_id INTEGER NOT NULL,
  150. campaign_id INTEGER NOT NULL,
  151. PRIMARY KEY (user_id, campaign_id)
  152. );
  153. ALTER TABLE maplog.user_to_campaign OWNER TO senslog;
  154. CREATE TYPE alert_status AS ENUM ('CREATED', 'INFORMED', 'IN_PROCESS', 'SOLVED', 'DELETED');
  155. CREATE TABLE maplog.alert (
  156. id BIGINT NOT NULL PRIMARY KEY,
  157. time_stamp TIMESTAMP WITH TIME ZONE NOT NULL,
  158. unit_id BIGINT NOT NULL,
  159. message TEXT NOT NULL,
  160. status alert_status NOT NULL,
  161. time_received TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL
  162. );
  163. ALTER TABLE maplog.alert OWNER TO senslog;
  164. CREATE SEQUENCE maplog.alert_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  165. ALTER TABLE maplog.alert_id_seq OWNER TO senslog;
  166. ALTER SEQUENCE maplog.alert_id_seq OWNED BY maplog.alert.id;
  167. ALTER TABLE ONLY maplog.alert ALTER COLUMN id SET DEFAULT nextval('maplog.alert_id_seq'::regclass);
  168. CREATE INDEX fki_obss_unitid_fk ON maplog.obs_telemetry USING btree (unit_id);
  169. CREATE INDEX fki_sens_phenom_fk ON maplog.sensor USING btree (phenomenon_id);
  170. CREATE INDEX fki_u2c_campid ON maplog.user_to_campaign USING btree (campaign_id);
  171. CREATE INDEX fki_u2c_campid_fk ON maplog.user_to_campaign USING btree (campaign_id);
  172. CREATE INDEX fki_u2c_userid_fk ON maplog.user_to_campaign USING btree (user_id);
  173. CREATE INDEX fki_un2c_campid ON maplog.unit_to_campaign USING btree (campaign_id);
  174. CREATE INDEX fki_un2c_unitid ON maplog.unit_to_campaign USING btree (unit_id);
  175. CREATE INDEX fki_unit_unittype_fk ON maplog.unit USING btree (unit_type_id);
  176. CREATE INDEX fki_uts_sensorid_fk ON maplog.unit_to_sensor USING btree (sensor_id);
  177. CREATE INDEX fki_uts_unitid_fk ON maplog.unit_to_sensor USING btree (unit_id);
  178. CREATE INDEX fki_dta_unitid_fk ON maplog.driver_to_action USING btree (unit_id);
  179. CREATE INDEX fki_dr2ac_driverid_fk ON maplog.driver_to_action USING btree (driver_id);
  180. CREATE INDEX fki_dr2ac_actionid_fk ON maplog.driver_to_action USING btree (action_id);
  181. CREATE INDEX fki_dr2ac_unitid_fk ON maplog.driver_to_action USING btree (unit_id);
  182. CREATE INDEX fki_alert_unitid_fk ON maplog.alert USING btree (unit_id);
  183. ALTER TABLE ONLY maplog.obs_telemetry ADD CONSTRAINT obss_unitid_fk FOREIGN KEY (unit_id) REFERENCES maplog.unit(unit_id) ON UPDATE CASCADE ON DELETE CASCADE;
  184. ALTER TABLE ONLY maplog.sensor ADD CONSTRAINT sens_phenom_fk FOREIGN KEY (phenomenon_id) REFERENCES maplog.phenomenon(id);
  185. ALTER TABLE ONLY maplog.user_to_campaign ADD CONSTRAINT u2c_campid FOREIGN KEY (campaign_id) REFERENCES maplog.campaign(id) ON UPDATE CASCADE ON DELETE CASCADE;
  186. ALTER TABLE ONLY maplog.user_to_campaign ADD CONSTRAINT u2c_userid_fk FOREIGN KEY (user_id) REFERENCES maplog.system_user(user_id) ON UPDATE CASCADE ON DELETE CASCADE;
  187. ALTER TABLE ONLY maplog.unit_to_campaign ADD CONSTRAINT un2c_campid FOREIGN KEY (campaign_id) REFERENCES maplog.campaign(id) ON UPDATE CASCADE ON DELETE CASCADE;
  188. ALTER TABLE ONLY maplog.unit_to_campaign ADD CONSTRAINT un2c_unitid FOREIGN KEY (unit_id) REFERENCES maplog.unit(unit_id) ON UPDATE CASCADE ON DELETE CASCADE;
  189. ALTER TABLE ONLY maplog.unit ADD CONSTRAINT unit_unittype_fk FOREIGN KEY (unit_type_id) REFERENCES maplog.unit_type(unit_type_id);
  190. ALTER TABLE ONLY maplog.unit_to_sensor ADD CONSTRAINT uts_sensorid_fk FOREIGN KEY (sensor_id) REFERENCES maplog.sensor(sensor_id) ON UPDATE CASCADE ON DELETE CASCADE;
  191. ALTER TABLE ONLY maplog.unit_to_sensor ADD CONSTRAINT uts_unitid_fk FOREIGN KEY (unit_id) REFERENCES maplog.unit(unit_id) ON UPDATE CASCADE ON DELETE CASCADE;
  192. ALTER TABLE ONLY maplog.driver_to_action ADD CONSTRAINT dta_unitid_fk FOREIGN KEY (unit_id) REFERENCES maplog.unit(unit_id) ON UPDATE CASCADE ON DELETE CASCADE;
  193. ALTER TABLE ONLY maplog.driver_to_action ADD CONSTRAINT dta_driverid_fk FOREIGN KEY (driver_id) REFERENCES maplog.driver(driver_id) ON UPDATE CASCADE ON DELETE CASCADE;
  194. ALTER TABLE ONLY maplog.driver_to_action ADD CONSTRAINT dta_actionid_fk FOREIGN KEY (action_id) REFERENCES maplog.action(action_id) ON UPDATE CASCADE ON DELETE CASCADE;
  195. ALTER TABLE ONLY maplog.alert ADD CONSTRAINT alert_unitid_fk FOREIGN KEY (unit_id) REFERENCES maplog.unit(unit_id) ON UPDATE CASCADE ON DELETE CASCADE;
  196. REVOKE USAGE ON SCHEMA public FROM PUBLIC;
  197. GRANT ALL ON SCHEMA public TO PUBLIC;