diff --git a/backend.py b/backend.py index 2c4b5cc..36884f6 100644 --- a/backend.py +++ b/backend.py @@ -22,29 +22,43 @@ class StatsResource(object): resp.status = falcon.HTTP_200 class EventResource(object): - def on_get(self, req, resp): + def on_get(self, req, resp, id): db = psycopg2.connect("dbname=oedb") cur = db.cursor() - print(req.params['id']) - # get data to display activity graphs - cur.execute("""select * from events where events_id='%s';""", req.params['id']) - e = cur.fetchone(e['events_tags']) - resp.body = e - resp.status = falcon.HTTP_200 + # get event geojson Feature + cur.execute(""" +SELECT format('{"type":"Feature", "properties": '|| events_tags::text ||', "geometry":'|| st_asgeojson(geom)) ||' }' +FROM events +JOIN geo ON (hash=events_geo) +WHERE events_id=%s;""", (id,)) + e = cur.fetchone() resp.set_header('X-Powered-By', 'OpenEventDatabase') resp.set_header('Access-Control-Allow-Origin', '*') resp.set_header('Access-Control-Allow-Headers', 'X-Requested-With') + if e is not None: + resp.body = e[0] + resp.status = falcon.HTTP_200 + else: + resp.status = falcon.HTTP_404 db.close() def on_post(self, req, resp): - # get request body payload (json) + # get request body payload (geojson Feature) body = req.stream.read().decode('utf-8') j=json.loads(body) - # connect to db and insert db = psycopg2.connect("dbname=oedb") cur = db.cursor() - cur.execute("""INSERT INTO events ( events_type, events_what, events_when, events_tags) VALUES (%s, %s, %s, %s) RETURNING events_id;""",(j['type'],j['what'],j['when'], body)) + # get the geometry part + geometry=json.dumps(j['geometry']) + # insert into geo table if not existing + cur.execute("""INSERT INTO geo (hash, geom) SELECT * FROM (SELECT md5(ewkt) as hash, st_setsrid(st_geomfromewkt(ewkt),4326) as geom FROM (SELECT st_asewkt(st_geomfromgeojson( %s )) as ewkt) as g) as i ON CONFLICT DO NOTHING RETURNING hash;""",(geometry,)) + # get its id (md5 hash) + h = cur.fetchone() + if h is None: + cur.execute("""SELECT md5(st_asewkt(st_geomfromgeojson( %s )));""",(geometry,)) + h = cur.fetchone() + cur.execute("""INSERT INTO events ( events_type, events_what, events_when, events_tags, events_geo) VALUES (%s, %s, %s, %s, %s) RETURNING events_id;""",(j['properties']['type'],j['properties']['what'],j['properties']['when'],json.dumps(j['properties']),h[0])) # get newly created event id e = cur.fetchone() db.commit() @@ -66,6 +80,7 @@ event = EventResource() stats = StatsResource() # things will handle all requests to the matching URL path +app.add_route('/event/{id}', event) # handle single event requests app.add_route('/event', event) # handle single event requests app.add_route('/stats', stats) diff --git a/setup.sql b/setup.sql index 1e6fc14..7c0c803 100644 --- a/setup.sql +++ b/setup.sql @@ -13,37 +13,6 @@ SET check_function_bodies = false; SET client_min_messages = warning; SET row_security = off; -SET search_path = public, pg_catalog; - -DROP TRIGGER events_lastupdate_trigger ON public.events; -DROP INDEX public.events_idx_where; -DROP INDEX public.events_idx_when; -DROP INDEX public.events_idx_what; -DROP INDEX public.events_idx_lastupdate; -DROP INDEX public.events_idx_id; -DROP INDEX public.events_idx_geom; -DROP TABLE public.events; -DROP FUNCTION public.events_lastupdate(); -DROP DOMAIN public.wgs84_lon; -DROP DOMAIN public.wgs84_lat; -DROP EXTENSION "uuid-ossp"; -DROP EXTENSION postgis; -DROP EXTENSION plpgsql; -DROP SCHEMA public; --- --- Name: public; Type: SCHEMA; Schema: -; Owner: - --- - -CREATE SCHEMA public; - - --- --- Name: SCHEMA public; Type: COMMENT; Schema: -; Owner: - --- - -COMMENT ON SCHEMA public IS 'standard public schema'; - - -- -- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: - -- @@ -123,22 +92,34 @@ SET default_with_oids = false; CREATE TABLE events ( events_what text, - events_where geometry, events_when timestamp with time zone, events_type text, events_tags json, events_id uuid DEFAULT uuid_generate_v4(), createdate timestamp without time zone DEFAULT now(), - events_geom geometry, - lastupdate timestamp without time zone + lastupdate timestamp without time zone, + events_geo text ); -- --- Name: events_idx_geom; Type: INDEX; Schema: public; Owner: - +-- Name: geo; Type: TABLE; Schema: public; Owner: - -- -CREATE INDEX events_idx_geom ON events USING gist (events_geom); +CREATE TABLE geo ( + insee character varying(80), + nom character varying(80), + geom geometry(Geometry,4326), + hash text +); + + +-- +-- Name: geo_hash_key; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY geo + ADD CONSTRAINT geo_hash_key UNIQUE (hash); -- @@ -170,27 +151,25 @@ CREATE INDEX events_idx_when ON events USING btree (events_when); -- --- Name: events_idx_where; Type: INDEX; Schema: public; Owner: - +-- Name: geo_geom; Type: INDEX; Schema: public; Owner: - -- -CREATE INDEX events_idx_where ON events USING gist (events_where); +CREATE INDEX geo_geom ON geo USING gist (geom); -- -- Name: events_lastupdate_trigger; Type: TRIGGER; Schema: public; Owner: - -- -CREATE TRIGGER events_lastupdate_trigger BEFORE UPDATE ON events FOR EACH ROW EXECUTE PROCEDURE events_lastupdate(); +CREATE TRIGGER events_lastupdate_trigger BEFORE INSERT OR UPDATE ON events FOR EACH ROW EXECUTE PROCEDURE events_lastupdate(); -- --- Name: public; Type: ACL; Schema: -; Owner: - +-- Name: geo_pk; Type: FK CONSTRAINT; Schema: public; Owner: - -- -REVOKE ALL ON SCHEMA public FROM PUBLIC; -REVOKE ALL ON SCHEMA public FROM postgres; -GRANT ALL ON SCHEMA public TO postgres; -GRANT ALL ON SCHEMA public TO PUBLIC; +ALTER TABLE ONLY events + ADD CONSTRAINT geo_pk FOREIGN KEY (events_geo) REFERENCES geo(hash); --