diff --git a/scripts/ddl.sql b/scripts/ddl.sql index 4f2724c..c80cd5c 100644 --- a/scripts/ddl.sql +++ b/scripts/ddl.sql @@ -1,10 +1,13 @@ CREATE EXTENSION IF NOT EXISTS "postgis"; CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "fuzzystrmatch"; + DROP TYPE IF EXISTS QUANTITY CASCADE; CREATE TYPE QUANTITY AS ENUM ('lots', 'many', 'few', 'none'); + DROP TYPE IF EXISTS CATEGORY CASCADE; CREATE TYPE CATEGORY AS ENUM ('beverages', 'desserts', 'entrees', 'other'); + DROP TABLE IF EXISTS food_items CASCADE; CREATE TABLE food_items ( id uuid PRIMARY KEY, @@ -14,25 +17,31 @@ CREATE TABLE food_items ( images VARCHAR, loc geography(POINT,4326) ); + DROP TABLE IF EXISTS images CASCADE; CREATE TABLE images ( filename VARCHAR(200) PRIMARY KEY, - food_item_id uuid REFERENCES food_items (id), + food_item_id uuid REFERENCES food_items (id) ON DELETE CASCADE, username VARCHAR(100), date timestamp (1) with time zone ); + DROP TABLE IF EXISTS quantities CASCADE; CREATE TABLE quantities ( - food_item_id uuid REFERENCES food_items (id), + food_item_id uuid REFERENCES food_items (id) ON DELETE CASCADE, date timestamp (1) with time zone, quantity QUANTITY, PRIMARY KEY(food_item_id, date) ); + + CREATE INDEX IF NOT EXISTS food_loc_index ON food_items USING GIST ( loc ); + DROP VIEW IF EXISTS latest_quantities; CREATE VIEW latest_quantities AS SELECT food_item_id, quantity, date from quantities q1 where date = ( SELECT max(date) FROM quantities q2 WHERE q1.food_item_id=q2.food_item_id ); + --INSERT INTO food_items (id, name, place_id, category, loc) -- VALUES ( -- uuid_generate_v4(),