From 6508885e4fa7de0dda3f21c1a4c2987754e898f9 Mon Sep 17 00:00:00 2001 From: Scott Rohde Date: Tue, 16 May 2017 21:56:23 -0500 Subject: [PATCH] Updated production_structure.sql file. --- db/production_structure.sql | 148 ++++++++++++++++++++++++++++++++++++ 1 file changed, 148 insertions(+) diff --git a/db/production_structure.sql b/db/production_structure.sql index 9a5ea4646..d86c89157 100644 --- a/db/production_structure.sql +++ b/db/production_structure.sql @@ -27,6 +27,58 @@ CREATE DOMAIN statnames AS text NOT NULL DEFAULT ''::text CONSTRAINT statnames_check CHECK ((VALUE = ANY (ARRAY['SD'::text, 'SE'::text, 'MSE'::text, '95%CI'::text, 'LSD'::text, 'MSD'::text, 'HSD'::text, ''::text]))); +-- +-- Name: check_correct_cultivar(); Type: FUNCTION; Schema: public; Owner: - +-- + +CREATE FUNCTION check_correct_cultivar() RETURNS trigger + LANGUAGE plpgsql + AS $$ +DECLARE + required_cultivar_id bigint; + required_specie_id bigint; +BEGIN + SELECT cultivar_id FROM sites_cultivars WHERE site_id = NEW.site_id INTO required_cultivar_id; + IF (required_cultivar_id IS NOT NULL) THEN + SELECT specie_id FROM cultivars WHERE id = required_cultivar_id INTO required_specie_id; + ELSE + SELECT specie_id FROM cultivars WHERE id = NEW.cultivar_id INTO required_specie_id; + END IF; + IF (required_cultivar_id IS NULL) THEN + IF (NEW.cultivar_id IS NULL) THEN + NULL; + ELSIF (NEW.specie_id IS NULL) THEN + NEW.specie_id := required_specie_id; + ELSIF (NEW.specie_id = required_specie_id) THEN + NULL; + ELSE + RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %.', NEW.specie_id, NEW.cultivar_id; + END IF; + ELSE + IF (NEW.cultivar_id IS NULL) THEN + IF (NEW.specie_id IS NULL) THEN + NEW.cultivar_id := required_cultivar_id; + NEW.specie_id := required_specie_id; + ELSIF (NEW.specie_id = required_specie_id) THEN + NEW.cultivar_id := required_cultivar_id; + ELSE + RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %. It should be %.', NEW.specie_id, required_cultivar_id, required_specie_id; + END IF; + ELSIF (NEW.cultivar_id = required_cultivar_id) THEN + IF (NEW.specie_id IS NULL) THEN + NEW.specie_id := required_specie_id; + ELSIF (NEW.specie_id != required_specie_id) THEN + RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %. It should be %.', NEW.specie_id, NEW.cultivar_id, required_specie_id; + END IF; + ELSE + RAISE EXCEPTION 'The value of cultivar_id (%) is not consistent with the value % specified for site_id %.', NEW.cultivar_id, required_cultivar_id, NEW.site_id; + END IF; + END IF; + RETURN NEW; +END; +$$; + + -- -- Name: check_for_references(); Type: FUNCTION; Schema: public; Owner: - -- @@ -809,6 +861,26 @@ END; $$; +-- +-- Name: set_correct_cultivar(); Type: FUNCTION; Schema: public; Owner: - +-- + +CREATE FUNCTION set_correct_cultivar() RETURNS trigger + LANGUAGE plpgsql + AS $$ +DECLARE + required_cultivar_id bigint; +BEGIN + IF (EXISTS(SELECT 1 FROM traits WHERE site_id = NEW.site_id AND cultivar_id != NEW.cultivar_id)) THEN + RAISE EXCEPTION 'Some existing traits have cultivar_id values inconsistent with this change.%', ''; + ELSE + UPDATE traits SET cultivar_id = NEW.cultivar_id WHERE site_id = NEW.site_id; + END IF; + RETURN NEW; +END; +$$; + + -- -- Name: site_or_utc_date(timestamp without time zone, text); Type: FUNCTION; Schema: public; Owner: - -- @@ -2795,6 +2867,38 @@ COMMENT ON COLUMN sites.som IS 'Depreciated'; COMMENT ON COLUMN sites.greenhouse IS 'Boolean: indicates if study was conducted in a field (0) or greenhouse, pot, or growth chamber (1)'; +-- +-- Name: sites_cultivars; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + +CREATE TABLE sites_cultivars ( + id bigint NOT NULL, + site_id bigint NOT NULL, + cultivar_id bigint NOT NULL, + created_at timestamp(6) without time zone DEFAULT utc_now(), + updated_at timestamp(6) without time zone DEFAULT utc_now() +); + + +-- +-- Name: sites_cultivars_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + +CREATE SEQUENCE sites_cultivars_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +-- +-- Name: sites_cultivars_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - +-- + +ALTER SEQUENCE sites_cultivars_id_seq OWNED BY sites_cultivars.id; + + -- -- Name: species_id_seq; Type: SEQUENCE; Schema: public; Owner: - -- @@ -3912,6 +4016,13 @@ ALTER TABLE ONLY sitegroups ALTER COLUMN id SET DEFAULT nextval('sitegroups_id_s ALTER TABLE ONLY sitegroups_sites ALTER COLUMN id SET DEFAULT nextval('sitegroups_sites_id_seq'::regclass); +-- +-- Name: id; Type: DEFAULT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY sites_cultivars ALTER COLUMN id SET DEFAULT nextval('sites_cultivars_id_seq'::regclass); + + -- -- Name: id; Type: DEFAULT; Schema: public; Owner: - -- @@ -4810,6 +4921,13 @@ CREATE UNIQUE INDEX trait_covariate_associations_uniqueness ON trait_covariate_a CREATE UNIQUE INDEX unique_schema_migrations ON schema_migrations USING btree (version); +-- +-- Name: ensure_correct_cultivar_for_site; Type: TRIGGER; Schema: public; Owner: - +-- + +CREATE TRIGGER ensure_correct_cultivar_for_site BEFORE INSERT OR UPDATE OF site_id, cultivar_id, specie_id ON traits FOR EACH ROW EXECUTE PROCEDURE check_correct_cultivar(); + + -- -- Name: forbid_dangling_input_references; Type: TRIGGER; Schema: public; Owner: - -- @@ -4914,6 +5032,13 @@ COMMENT ON TRIGGER restrict_trait_range ON traits IS 'Trigger function to ensure A NULL in the min or max column means "no limit".'; +-- +-- Name: set_correct_cultivar_for_site; Type: TRIGGER; Schema: public; Owner: - +-- + +CREATE TRIGGER set_correct_cultivar_for_site BEFORE INSERT OR UPDATE ON sites_cultivars FOR EACH ROW EXECUTE PROCEDURE set_correct_cultivar(); + + -- -- Name: update_citations_sites_timestamp; Type: TRIGGER; Schema: public; Owner: - -- @@ -5159,6 +5284,13 @@ CREATE TRIGGER update_runs_timestamp BEFORE UPDATE ON runs FOR EACH ROW EXECUTE CREATE TRIGGER update_sessions_timestamp BEFORE UPDATE ON sessions FOR EACH ROW EXECUTE PROCEDURE update_timestamp(); +-- +-- Name: update_sites_cultivars_timestamp; Type: TRIGGER; Schema: public; Owner: - +-- + +CREATE TRIGGER update_sites_cultivars_timestamp BEFORE UPDATE ON sites_cultivars FOR EACH ROW EXECUTE PROCEDURE update_timestamp(); + + -- -- Name: update_sites_timestamp; Type: TRIGGER; Schema: public; Owner: - -- @@ -5350,6 +5482,14 @@ ALTER TABLE ONLY cultivars_pfts COMMENT ON CONSTRAINT cultivar_exists ON cultivars_pfts IS 'Ensure the referred-to cultivar exists, block its deletion if it is being used in a pft, and update the reference if the cultivar id number changes.'; +-- +-- Name: cultivar_exists; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY sites_cultivars + ADD CONSTRAINT cultivar_exists FOREIGN KEY (cultivar_id) REFERENCES cultivars(id) ON UPDATE CASCADE; + + -- -- Name: fk_citations_sites_citations_1; Type: FK CONSTRAINT; Schema: public; Owner: - -- @@ -5972,6 +6112,14 @@ ALTER TABLE ONLY reference_runs ADD CONSTRAINT reference_runs_model_id_fkey FOREIGN KEY (model_id) REFERENCES models(id) ON UPDATE CASCADE ON DELETE RESTRICT; +-- +-- Name: site_exists; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY sites_cultivars + ADD CONSTRAINT site_exists FOREIGN KEY (site_id) REFERENCES sites(id) ON UPDATE CASCADE; + + -- -- Name: species_exists; Type: FK CONSTRAINT; Schema: public; Owner: - --