init.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288
  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. campaign_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. );
  40. ALTER TABLE maplog.campaign OWNER TO senslog;
  41. CREATE SEQUENCE maplog.campaign_campaign_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  42. ALTER TABLE maplog.campaign_campaign_id_seq OWNER TO senslog;
  43. ALTER SEQUENCE maplog.campaign_campaign_id_seq OWNED BY maplog.campaign.campaign_id;
  44. ALTER TABLE ONLY maplog.campaign ALTER COLUMN campaign_id SET DEFAULT nextval('maplog.campaign_campaign_id_seq'::regclass);
  45. CREATE TABLE maplog.obs_telemetry (
  46. obs_id BIGINT NOT NULL PRIMARY KEY,
  47. time_stamp TIMESTAMP WITH TIME ZONE NOT NULL,
  48. unit_id BIGINT NOT NULL,
  49. observed_values jsonb NOT NULL,
  50. the_geom geometry,
  51. speed INTEGER NOT NULL,
  52. time_received TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL
  53. );
  54. ALTER TABLE maplog.obs_telemetry OWNER TO senslog;
  55. CREATE SEQUENCE maplog.obs_telemetry_obs_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  56. ALTER TABLE maplog.obs_telemetry_obs_id_seq OWNER TO senslog;
  57. ALTER SEQUENCE maplog.obs_telemetry_obs_id_seq OWNED BY maplog.obs_telemetry.obs_id;
  58. ALTER TABLE ONLY maplog.obs_telemetry ALTER COLUMN obs_id SET DEFAULT nextval('maplog.obs_telemetry_obs_id_seq'::regclass);
  59. CREATE TABLE maplog.driver (
  60. id INTEGER NOT NULL PRIMARY KEY,
  61. name VARCHAR(100) NOT NULL
  62. );
  63. ALTER TABLE maplog.driver OWNER TO senslog;
  64. CREATE SEQUENCE maplog.driver_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  65. ALTER TABLE maplog.driver_id_seq OWNER TO senslog;
  66. ALTER SEQUENCE maplog.driver_id_seq OWNED BY maplog.driver.id;
  67. ALTER TABLE ONLY maplog.driver ALTER COLUMN id SET DEFAULT nextval('maplog.driver_id_seq'::regclass);
  68. CREATE TABLE maplog.action (
  69. id INTEGER NOT NULL PRIMARY KEY,
  70. name VARCHAR(100) NOT NULL
  71. );
  72. ALTER TABLE maplog.action OWNER TO senslog;
  73. CREATE SEQUENCE maplog.action_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  74. ALTER TABLE maplog.action_id_seq OWNER TO senslog;
  75. ALTER SEQUENCE maplog.action_id_seq OWNED BY maplog.driver.id;
  76. ALTER TABLE ONLY maplog.action ALTER COLUMN id SET DEFAULT nextval('maplog.action_id_seq'::regclass);
  77. CREATE TABLE maplog.driver_to_action (
  78. id INTEGER NOT NULL PRIMARY KEY,
  79. driver_id INTEGER NOT NULL,
  80. action_id INTEGER NOT NULL,
  81. unit_id BIGINT NOT NULL,
  82. from_time TIMESTAMP WITH TIME ZONE NOT NULL,
  83. to_time TIMESTAMP WITH TIME ZONE
  84. );
  85. ALTER TABLE maplog.driver_to_action OWNER TO senslog;
  86. CREATE SEQUENCE maplog.driver_to_action_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  87. ALTER TABLE maplog.driver_to_action_id_seq OWNER TO senslog;
  88. ALTER SEQUENCE maplog.driver_to_action_id_seq OWNED BY maplog.driver_to_action.id;
  89. ALTER TABLE ONLY maplog.driver_to_action ALTER COLUMN id SET DEFAULT nextval('maplog.driver_to_action_id_seq'::regclass);
  90. CREATE TABLE maplog.phenomenon (
  91. id INTEGER NOT NULL PRIMARY KEY,
  92. name TEXT NOT NULL,
  93. uom CHARACTER VARYING(30) NOT NULL,
  94. uom_link TEXT
  95. );
  96. ALTER TABLE maplog.phenomenon OWNER TO senslog;
  97. CREATE SEQUENCE maplog.phenomenon_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  98. ALTER TABLE maplog.phenomenon_id_seq OWNER TO senslog;
  99. ALTER SEQUENCE maplog.phenomenon_id_seq OWNED BY maplog.phenomenon.id;
  100. ALTER TABLE ONLY maplog.phenomenon ALTER COLUMN id SET DEFAULT nextval('maplog.phenomenon_id_seq'::regclass);
  101. CREATE TABLE maplog.sensor (
  102. sensor_id BIGINT NOT NULL PRIMARY KEY,
  103. sensor_name CHARACTER VARYING(100) UNIQUE NOT NULL,
  104. sensor_type TEXT,
  105. description TEXT,
  106. io_id INTEGER,
  107. phenomenon_id INTEGER NOT NULL
  108. );
  109. ALTER TABLE maplog.sensor OWNER TO senslog;
  110. CREATE SEQUENCE maplog.sensor_sensor_id_seq START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  111. ALTER TABLE maplog.sensor_sensor_id_seq OWNER TO senslog;
  112. ALTER SEQUENCE maplog.sensor_sensor_id_seq OWNED BY maplog.sensor.sensor_id;
  113. ALTER TABLE ONLY maplog.sensor ALTER COLUMN sensor_id SET DEFAULT nextval('maplog.sensor_sensor_id_seq'::regclass);
  114. CREATE TABLE maplog.system_user (
  115. user_id INTEGER NOT NULL PRIMARY KEY,
  116. name TEXT NOT NULL
  117. );
  118. ALTER TABLE maplog.system_user OWNER TO senslog;
  119. CREATE TABLE maplog.unit (
  120. unit_id BIGINT NOT NULL PRIMARY KEY,
  121. imei CHARACTER VARYING(20) NOT NULL UNIQUE,
  122. name CHARACTER VARYING(100) NOT NULL,
  123. description TEXT,
  124. is_mobile boolean DEFAULT true NOT NULL,
  125. unit_type_id CHARACTER VARYING(2) DEFAULT 'X'::CHARACTER VARYING NOT NULL
  126. );
  127. ALTER TABLE maplog.unit OWNER TO senslog;
  128. CREATE TABLE maplog.unit_to_campaign (
  129. id INTEGER NOT NULL PRIMARY KEY,
  130. camp_id INTEGER NOT NULL,
  131. unit_id BIGINT NOT NULL,
  132. from_time TIMESTAMP WITH TIME ZONE NOT NULL,
  133. to_time TIMESTAMP WITH TIME ZONE NOT NULL
  134. );
  135. ALTER TABLE maplog.unit_to_campaign OWNER TO senslog;
  136. CREATE SEQUENCE maplog.unit_to_campaign_id_seq AS INTEGER START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1;
  137. ALTER TABLE maplog.unit_to_campaign_id_seq OWNER TO senslog;
  138. ALTER SEQUENCE maplog.unit_to_campaign_id_seq OWNED BY maplog.unit_to_campaign.id;
  139. ALTER TABLE ONLY maplog.unit_to_campaign ALTER COLUMN id SET DEFAULT nextval('maplog.unit_to_campaign_id_seq'::regclass);
  140. CREATE TABLE maplog.unit_to_sensor (
  141. sensor_id BIGINT NOT NULL,
  142. unit_id BIGINT NOT NULL,
  143. PRIMARY KEY (unit_id, sensor_id)
  144. );
  145. ALTER TABLE maplog.unit_to_sensor OWNER TO senslog;
  146. CREATE TABLE maplog.unit_type (
  147. unit_type_id CHARACTER VARYING(2) NOT NULL PRIMARY KEY,
  148. type_name CHARACTER VARYING(20) NOT NULL,
  149. description TEXT
  150. );
  151. ALTER TABLE maplog.unit_type OWNER TO senslog;
  152. CREATE TABLE maplog.user_to_campaign (
  153. user_id INTEGER NOT NULL,
  154. campaign_id INTEGER NOT NULL,
  155. PRIMARY KEY (user_id, campaign_id)
  156. );
  157. ALTER TABLE maplog.user_to_campaign OWNER TO senslog;
  158. CREATE INDEX fki_obss_unitid_fk ON maplog.obs_telemetry USING btree (unit_id);
  159. CREATE INDEX fki_sens_phenom_fk ON maplog.sensor USING btree (phenomenon_id);
  160. CREATE INDEX fki_u2c_campid ON maplog.user_to_campaign USING btree (campaign_id);
  161. CREATE INDEX fki_u2c_campid_fk ON maplog.user_to_campaign USING btree (campaign_id);
  162. CREATE INDEX fki_u2c_userid_fk ON maplog.user_to_campaign USING btree (user_id);
  163. CREATE INDEX fki_un2c_campid ON maplog.unit_to_campaign USING btree (camp_id);
  164. CREATE INDEX fki_un2c_unitid ON maplog.unit_to_campaign USING btree (unit_id);
  165. CREATE INDEX fki_unit_unittype_fk ON maplog.unit USING btree (unit_type_id);
  166. CREATE INDEX fki_uts_sensorid_fk ON maplog.unit_to_sensor USING btree (sensor_id);
  167. CREATE INDEX fki_uts_unitid_fk ON maplog.unit_to_sensor USING btree (unit_id);
  168. CREATE INDEX fki_dta_unitid_fk ON maplog.driver_to_action USING btree (unit_id);
  169. CREATE INDEX fki_dr2ac_driverid_fk ON maplog.driver_to_action USING btree (driver_id);
  170. CREATE INDEX fki_dr2ac_actionid_fk ON maplog.driver_to_action USING btree (action_id);
  171. CREATE INDEX fki_dr2ac_unitid_fk ON maplog.driver_to_action USING btree (unit_id);
  172. 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;
  173. ALTER TABLE ONLY maplog.sensor ADD CONSTRAINT sens_phenom_fk FOREIGN KEY (phenomenon_id) REFERENCES maplog.phenomenon(id);
  174. ALTER TABLE ONLY maplog.user_to_campaign ADD CONSTRAINT u2c_campid FOREIGN KEY (campaign_id) REFERENCES maplog.campaign(campaign_id) ON UPDATE CASCADE ON DELETE CASCADE;
  175. 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;
  176. ALTER TABLE ONLY maplog.unit_to_campaign ADD CONSTRAINT un2c_campid FOREIGN KEY (camp_id) REFERENCES maplog.campaign(campaign_id) ON UPDATE CASCADE ON DELETE CASCADE;
  177. 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;
  178. ALTER TABLE ONLY maplog.unit ADD CONSTRAINT unit_unittype_fk FOREIGN KEY (unit_type_id) REFERENCES maplog.unit_type(unit_type_id);
  179. 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;
  180. 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;
  181. 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;
  182. ALTER TABLE ONLY maplog.driver_to_action ADD CONSTRAINT dta_driverid_fk FOREIGN KEY (driver_id) REFERENCES maplog.driver(id) ON UPDATE CASCADE ON DELETE CASCADE;
  183. ALTER TABLE ONLY maplog.driver_to_action ADD CONSTRAINT dta_actionid_fk FOREIGN KEY (action_id) REFERENCES maplog.action(id) ON UPDATE CASCADE ON DELETE CASCADE;
  184. REVOKE USAGE ON SCHEMA public FROM PUBLIC;
  185. GRANT ALL ON SCHEMA public TO PUBLIC;