From a4f3d58c1a5790c13438c1952ac04c773c7506a7 Mon Sep 17 00:00:00 2001 From: Matthew Berryman Date: Mon, 27 Feb 2017 19:43:54 +1100 Subject: [PATCH 1/2] Zurich schema and fns (fns need work) --- schema/reports/zurich/zurich.functions.sql | 24 +++++++++++++++ schema/reports/zurich/zurich.schema.sql | 34 ++++++++++++++++++++++ 2 files changed, 58 insertions(+) create mode 100644 schema/reports/zurich/zurich.functions.sql create mode 100644 schema/reports/zurich/zurich.schema.sql diff --git a/schema/reports/zurich/zurich.functions.sql b/schema/reports/zurich/zurich.functions.sql new file mode 100644 index 0000000..0b097ea --- /dev/null +++ b/schema/reports/zurich/zurich.functions.sql @@ -0,0 +1,24 @@ +-- Create Trigger Function to update all_reports table +CREATE OR REPLACE FUNCTION zurich.update_all_reports_from_zurich() + RETURNS trigger AS +$BODY$ + BEGIN + IF (TG_OP = 'UPDATE') THEN + INSERT INTO cognicity.all_reports (fkey, created_at, text, source, disaster_type, lang, url, image_url, title, the_geom) SELECT NEW.pkey, NEW.created_at, NEW.text, 'zurich', NEW.disaster_type, NEW.lang, NEW.url, NEW.image_url, NEW.title, NEW.the_geom; + RETURN NEW; + ELSIF (TG_OP = 'INSERT') THEN + INSERT INTO cognicity.all_reports (fkey, created_at, text, source, disaster_type, lang, url, image_url, title, the_geom) SELECT NEW.pkey, NEW.created_at, NEW.text, 'zurich', NEW.disaster_type, NEW.lang, NEW.url, NEW.image_url, NEW.title, NEW.the_geom; + RETURN NEW; + END IF; + END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +ALTER FUNCTION zurich.update_all_reports_from_zurich() + OWNER TO postgres; + +CREATE TRIGGER trigger_update_all_reports_from_zurich + BEFORE INSERT OR UPDATE + ON zurich.reports + FOR EACH ROW + EXECUTE PROCEDURE zurich.update_all_reports_from_zurich(); diff --git a/schema/reports/zurich/zurich.schema.sql b/schema/reports/zurich/zurich.schema.sql new file mode 100644 index 0000000..524f165 --- /dev/null +++ b/schema/reports/zurich/zurich.schema.sql @@ -0,0 +1,34 @@ +-- Schema for zurich data +CREATE SCHEMA zurich; + +-- Create table for zurich reports +CREATE TABLE zurich.reports +( + pkey bigserial NOT NULL, + contribution_id bigint NOT NULL UNIQUE, + database_time timestamp with time zone DEFAULT now(), + created_at timestamp with time zone, + disaster_type character varying NOT NULL, + text character varying, + lang character varying, + url character varying, + image_url character varying, + title character varying, + city character varying, + CONSTRAINT pkey_zurich PRIMARY KEY (pkey) +); + +-- Add Geometry column to tweet_reports +SELECT AddGeometryColumn ('zurich','reports','the_geom',4326,'POINT',2); + +-- Add GIST spatial index +CREATE INDEX gix_zurich_reports ON zurich.reports USING gist (the_geom); + +-- Create table for zurich report users +CREATE TABLE zurich.users +( + pkey bigserial, + user_hash character varying UNIQUE, + reports_count integer , + CONSTRAINT pkey_zurich_users PRIMARY KEY (pkey) +); From fa19d861ebce80a194a51e7de6815cdea16ffafd Mon Sep 17 00:00:00 2001 From: Matthew Berryman Date: Tue, 28 Feb 2017 10:16:52 +1100 Subject: [PATCH 2/2] post_id for zurich --- schema/reports/zurich/zurich.schema.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/schema/reports/zurich/zurich.schema.sql b/schema/reports/zurich/zurich.schema.sql index 524f165..954dc9b 100644 --- a/schema/reports/zurich/zurich.schema.sql +++ b/schema/reports/zurich/zurich.schema.sql @@ -5,7 +5,7 @@ CREATE SCHEMA zurich; CREATE TABLE zurich.reports ( pkey bigserial NOT NULL, - contribution_id bigint NOT NULL UNIQUE, + post_id bigint NOT NULL UNIQUE, database_time timestamp with time zone DEFAULT now(), created_at timestamp with time zone, disaster_type character varying NOT NULL,