Skip to content

Commit 6508885

Browse files
committed
Updated production_structure.sql file.
1 parent 523d4be commit 6508885

File tree

1 file changed

+148
-0
lines changed

1 file changed

+148
-0
lines changed

db/production_structure.sql

Lines changed: 148 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -27,6 +27,58 @@ CREATE DOMAIN statnames AS text NOT NULL DEFAULT ''::text
2727
CONSTRAINT statnames_check CHECK ((VALUE = ANY (ARRAY['SD'::text, 'SE'::text, 'MSE'::text, '95%CI'::text, 'LSD'::text, 'MSD'::text, 'HSD'::text, ''::text])));
2828

2929

30+
--
31+
-- Name: check_correct_cultivar(); Type: FUNCTION; Schema: public; Owner: -
32+
--
33+
34+
CREATE FUNCTION check_correct_cultivar() RETURNS trigger
35+
LANGUAGE plpgsql
36+
AS $$
37+
DECLARE
38+
required_cultivar_id bigint;
39+
required_specie_id bigint;
40+
BEGIN
41+
SELECT cultivar_id FROM sites_cultivars WHERE site_id = NEW.site_id INTO required_cultivar_id;
42+
IF (required_cultivar_id IS NOT NULL) THEN
43+
SELECT specie_id FROM cultivars WHERE id = required_cultivar_id INTO required_specie_id;
44+
ELSE
45+
SELECT specie_id FROM cultivars WHERE id = NEW.cultivar_id INTO required_specie_id;
46+
END IF;
47+
IF (required_cultivar_id IS NULL) THEN
48+
IF (NEW.cultivar_id IS NULL) THEN
49+
NULL;
50+
ELSIF (NEW.specie_id IS NULL) THEN
51+
NEW.specie_id := required_specie_id;
52+
ELSIF (NEW.specie_id = required_specie_id) THEN
53+
NULL;
54+
ELSE
55+
RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %.', NEW.specie_id, NEW.cultivar_id;
56+
END IF;
57+
ELSE
58+
IF (NEW.cultivar_id IS NULL) THEN
59+
IF (NEW.specie_id IS NULL) THEN
60+
NEW.cultivar_id := required_cultivar_id;
61+
NEW.specie_id := required_specie_id;
62+
ELSIF (NEW.specie_id = required_specie_id) THEN
63+
NEW.cultivar_id := required_cultivar_id;
64+
ELSE
65+
RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %. It should be %.', NEW.specie_id, required_cultivar_id, required_specie_id;
66+
END IF;
67+
ELSIF (NEW.cultivar_id = required_cultivar_id) THEN
68+
IF (NEW.specie_id IS NULL) THEN
69+
NEW.specie_id := required_specie_id;
70+
ELSIF (NEW.specie_id != required_specie_id) THEN
71+
RAISE EXCEPTION 'The species id % is not consistent with the cultivar id %. It should be %.', NEW.specie_id, NEW.cultivar_id, required_specie_id;
72+
END IF;
73+
ELSE
74+
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;
75+
END IF;
76+
END IF;
77+
RETURN NEW;
78+
END;
79+
$$;
80+
81+
3082
--
3183
-- Name: check_for_references(); Type: FUNCTION; Schema: public; Owner: -
3284
--
@@ -809,6 +861,26 @@ END;
809861
$$;
810862
811863
864+
--
865+
-- Name: set_correct_cultivar(); Type: FUNCTION; Schema: public; Owner: -
866+
--
867+
868+
CREATE FUNCTION set_correct_cultivar() RETURNS trigger
869+
LANGUAGE plpgsql
870+
AS $$
871+
DECLARE
872+
required_cultivar_id bigint;
873+
BEGIN
874+
IF (EXISTS(SELECT 1 FROM traits WHERE site_id = NEW.site_id AND cultivar_id != NEW.cultivar_id)) THEN
875+
RAISE EXCEPTION 'Some existing traits have cultivar_id values inconsistent with this change.%', '';
876+
ELSE
877+
UPDATE traits SET cultivar_id = NEW.cultivar_id WHERE site_id = NEW.site_id;
878+
END IF;
879+
RETURN NEW;
880+
END;
881+
$$;
882+
883+
812884
--
813885
-- Name: site_or_utc_date(timestamp without time zone, text); Type: FUNCTION; Schema: public; Owner: -
814886
--
@@ -2795,6 +2867,38 @@ COMMENT ON COLUMN sites.som IS 'Depreciated';
27952867
COMMENT ON COLUMN sites.greenhouse IS 'Boolean: indicates if study was conducted in a field (0) or greenhouse, pot, or growth chamber (1)';
27962868
27972869
2870+
--
2871+
-- Name: sites_cultivars; Type: TABLE; Schema: public; Owner: -; Tablespace:
2872+
--
2873+
2874+
CREATE TABLE sites_cultivars (
2875+
id bigint NOT NULL,
2876+
site_id bigint NOT NULL,
2877+
cultivar_id bigint NOT NULL,
2878+
created_at timestamp(6) without time zone DEFAULT utc_now(),
2879+
updated_at timestamp(6) without time zone DEFAULT utc_now()
2880+
);
2881+
2882+
2883+
--
2884+
-- Name: sites_cultivars_id_seq; Type: SEQUENCE; Schema: public; Owner: -
2885+
--
2886+
2887+
CREATE SEQUENCE sites_cultivars_id_seq
2888+
START WITH 1
2889+
INCREMENT BY 1
2890+
NO MINVALUE
2891+
NO MAXVALUE
2892+
CACHE 1;
2893+
2894+
2895+
--
2896+
-- Name: sites_cultivars_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
2897+
--
2898+
2899+
ALTER SEQUENCE sites_cultivars_id_seq OWNED BY sites_cultivars.id;
2900+
2901+
27982902
--
27992903
-- Name: species_id_seq; Type: SEQUENCE; Schema: public; Owner: -
28002904
--
@@ -3912,6 +4016,13 @@ ALTER TABLE ONLY sitegroups ALTER COLUMN id SET DEFAULT nextval('sitegroups_id_s
39124016
ALTER TABLE ONLY sitegroups_sites ALTER COLUMN id SET DEFAULT nextval('sitegroups_sites_id_seq'::regclass);
39134017
39144018
4019+
--
4020+
-- Name: id; Type: DEFAULT; Schema: public; Owner: -
4021+
--
4022+
4023+
ALTER TABLE ONLY sites_cultivars ALTER COLUMN id SET DEFAULT nextval('sites_cultivars_id_seq'::regclass);
4024+
4025+
39154026
--
39164027
-- Name: id; Type: DEFAULT; Schema: public; Owner: -
39174028
--
@@ -4810,6 +4921,13 @@ CREATE UNIQUE INDEX trait_covariate_associations_uniqueness ON trait_covariate_a
48104921
CREATE UNIQUE INDEX unique_schema_migrations ON schema_migrations USING btree (version);
48114922
48124923
4924+
--
4925+
-- Name: ensure_correct_cultivar_for_site; Type: TRIGGER; Schema: public; Owner: -
4926+
--
4927+
4928+
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();
4929+
4930+
48134931
--
48144932
-- Name: forbid_dangling_input_references; Type: TRIGGER; Schema: public; Owner: -
48154933
--
@@ -4914,6 +5032,13 @@ COMMENT ON TRIGGER restrict_trait_range ON traits IS 'Trigger function to ensure
49145032
A NULL in the min or max column means "no limit".';
49155033
49165034
5035+
--
5036+
-- Name: set_correct_cultivar_for_site; Type: TRIGGER; Schema: public; Owner: -
5037+
--
5038+
5039+
CREATE TRIGGER set_correct_cultivar_for_site BEFORE INSERT OR UPDATE ON sites_cultivars FOR EACH ROW EXECUTE PROCEDURE set_correct_cultivar();
5040+
5041+
49175042
--
49185043
-- Name: update_citations_sites_timestamp; Type: TRIGGER; Schema: public; Owner: -
49195044
--
@@ -5159,6 +5284,13 @@ CREATE TRIGGER update_runs_timestamp BEFORE UPDATE ON runs FOR EACH ROW EXECUTE
51595284
CREATE TRIGGER update_sessions_timestamp BEFORE UPDATE ON sessions FOR EACH ROW EXECUTE PROCEDURE update_timestamp();
51605285
51615286
5287+
--
5288+
-- Name: update_sites_cultivars_timestamp; Type: TRIGGER; Schema: public; Owner: -
5289+
--
5290+
5291+
CREATE TRIGGER update_sites_cultivars_timestamp BEFORE UPDATE ON sites_cultivars FOR EACH ROW EXECUTE PROCEDURE update_timestamp();
5292+
5293+
51625294
--
51635295
-- Name: update_sites_timestamp; Type: TRIGGER; Schema: public; Owner: -
51645296
--
@@ -5350,6 +5482,14 @@ ALTER TABLE ONLY cultivars_pfts
53505482
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.';
53515483
53525484
5485+
--
5486+
-- Name: cultivar_exists; Type: FK CONSTRAINT; Schema: public; Owner: -
5487+
--
5488+
5489+
ALTER TABLE ONLY sites_cultivars
5490+
ADD CONSTRAINT cultivar_exists FOREIGN KEY (cultivar_id) REFERENCES cultivars(id) ON UPDATE CASCADE;
5491+
5492+
53535493
--
53545494
-- Name: fk_citations_sites_citations_1; Type: FK CONSTRAINT; Schema: public; Owner: -
53555495
--
@@ -5972,6 +6112,14 @@ ALTER TABLE ONLY reference_runs
59726112
ADD CONSTRAINT reference_runs_model_id_fkey FOREIGN KEY (model_id) REFERENCES models(id) ON UPDATE CASCADE ON DELETE RESTRICT;
59736113
59746114
6115+
--
6116+
-- Name: site_exists; Type: FK CONSTRAINT; Schema: public; Owner: -
6117+
--
6118+
6119+
ALTER TABLE ONLY sites_cultivars
6120+
ADD CONSTRAINT site_exists FOREIGN KEY (site_id) REFERENCES sites(id) ON UPDATE CASCADE;
6121+
6122+
59756123
--
59766124
-- Name: species_exists; Type: FK CONSTRAINT; Schema: public; Owner: -
59776125
--

0 commit comments

Comments
 (0)