-- Existing tables CREATE TABLE aux_role ( role_id int(11) NOT NULL AUTO_INCREMENT, rolecode character varying(30) NOT NULL, roledescription character varying(200), CONSTRAINT aux_role_pkey PRIMARY KEY (role_id ) ); CREATE TABLE reference ( reference_id int(11) NOT NULL AUTO_INCREMENT, shortname character varying(250), fulltext__ text, referencetype character varying(250) ); CREATE TABLE party ( party_id int(11) NOT NULL AUTO_INCREMENT, salutation character varying(20), givenname character varying(50), middlename character varying(50), surname character varying(50), organizationname character varying(100) ); CREATE TABLE plantname ( plantname_id int(11) NOT NULL AUTO_INCREMENT, plantname character varying(255) NOT NULL, reference_id int(11), dateentered timestamp DEFAULT now(), CONSTRAINT plantname_pkey PRIMARY KEY (plantname_id ), CONSTRAINT plantname_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE ); CREATE TABLE plantconcept ( plantconcept_id int(11) NOT NULL AUTO_INCREMENT, plantname_id int(11) NOT NULL, reference_id int(11) NOT NULL, plantname character varying(200), plantcode character varying(23), plantdescription text, d_obscount int(11), d_currentaccepted int(1), accessioncode character varying(255), CONSTRAINT plantconcept_pkey PRIMARY KEY (plantconcept_id ), CONSTRAINT plantconcept_plantname_id FOREIGN KEY (plantname_id) REFERENCES plantname (plantname_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT plantconcept_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE ); CREATE TABLE namedplace ( namedplace_id int(11) NOT NULL AUTO_INCREMENT, placesystem character varying(50), placename character varying(100) NOT NULL, placedescription text, placecode character varying(15), owner character varying(100), reference_id int(11), d_obscount int(11), accessioncode character varying(255), CONSTRAINT namedplace_pkey PRIMARY KEY (namedplace_id ), CONSTRAINT namedplace_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT namedplace_keys UNIQUE (placesystem , placename ) ); CREATE TABLE project ( project_id int(11) NOT NULL AUTO_INCREMENT, projectname character varying(150) NOT NULL, projectdescription text, startdate timestamp, stopdate timestamp, d_obscount int(11), d_lastlocationaddeddate timestamp, accessioncode character varying(255), CONSTRAINT project_pkey PRIMARY KEY (project_id ), CONSTRAINT project_keys UNIQUE (projectname , startdate , stopdate ) ); -- New tables CREATE TABLE location ( location_id int(11) NOT NULL AUTO_INCREMENT, sourceid character varying(30), reference_id int(11), parent_id int(11), reallatitude double precision, reallongitude double precision, locationaccuracy double precision, confidentialitystatus int(11) NOT NULL, confidentialityreason character varying(200), latitude double precision, longitude double precision, -- ... accessioncode character varying(255), sublocationxposition double precision, sublocationyposition double precision, namedplace_id int(11), CONSTRAINT location_pkey PRIMARY KEY (location_id ), CONSTRAINT location_namedplace_id FOREIGN KEY (namedplace_id) REFERENCES namedplace (namedplace_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT location_parent_id FOREIGN KEY (parent_id) REFERENCES location (location_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT location_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT location_keys UNIQUE (reference_id , parent_id , sourceid ) ); CREATE TABLE locationevent -- VegBank's observation table. ( locationevent_id int(11) NOT NULL AUTO_INCREMENT, previous_id int(11), location_id int(11) NOT NULL, project_id int(11), sourceid character varying(30), -- ... accessioncode character varying(255), CONSTRAINT locationevent_pkey PRIMARY KEY (locationevent_id ), CONSTRAINT locationevent_location_id FOREIGN KEY (location_id) REFERENCES location (location_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT locationevent_project_id FOREIGN KEY (project_id) REFERENCES project (project_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT locationevent_keys UNIQUE (location_id , project_id , sourceid ) ); CREATE TABLE taxonoccurrence -- VegBank's taxonobservation table. ( taxonoccurrence_id int(11) NOT NULL AUTO_INCREMENT, locationevent_id int(11) NOT NULL, authorplantname character varying(255), reference_id int(11), taxoninferencearea double precision, emb_taxonoccurrence int(11), int_origplantconcept_id int(11), int_origplantscifull character varying(255), int_origplantscinamenoauth character varying(255), int_origplantcommon character varying(255), int_origplantcode character varying(255), int_currplantconcept_id int(11), int_currplantscifull character varying(255), int_currplantscinamenoauth character varying(255), int_currplantcommon character varying(255), int_currplantcode character varying(255), accessioncode character varying(255), CONSTRAINT taxonoccurrence_pkey PRIMARY KEY (taxonoccurrence_id ), CONSTRAINT taxonoccurrence_locationevent_id FOREIGN KEY (locationevent_id) REFERENCES locationevent (locationevent_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT taxonoccurrence_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE ); CREATE TABLE aggregateoccurrence -- VegBank's taxonimportance table. ( aggregateoccurrence_id int(11) NOT NULL AUTO_INCREMENT, taxonoccurrence_id int(11) NOT NULL, taxonbin_id int(11), cover double precision, basalarea double precision, biomass double precision, inferencearea double precision, stratumbase double precision, stratumheight double precision, emb_aggregateoccurrence int(11), covercode character varying(10), count int(11) NOT NULL, accessioncode character varying(255), CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ), CONSTRAINT aggregateoccurrence_taxonbin_id FOREIGN KEY (taxonbin_id) REFERENCES taxonbin (taxonbin_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id) REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT aggregateoccurrence_keys UNIQUE (taxonoccurrence_id , taxonbin_id ) ); CREATE TABLE individualplant -- VegBank's stemcount table. ( individualplant_id int(11) NOT NULL AUTO_INCREMENT, aggregateoccurrence_id int(11) NOT NULL, height double precision, heightaccuracy double precision, emb_individualplant int(11), sourceid character varying(20), accessioncode character varying(255), stemcount int(11), CONSTRAINT individualplant_pkey PRIMARY KEY (individualplant_id ), CONSTRAINT individualplant_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id) REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT individualplant_keys UNIQUE (aggregateoccurrence_id , sourceid ) ); CREATE TABLE stem -- VegBank's stemlocation table. ( stem_id int(11) NOT NULL AUTO_INCREMENT, individualplant_id int(11) NOT NULL, sourceid character varying(20), xposition double precision, yposition double precision, health character varying(50), emb_stem int(11), diameter double precision, height double precision, heightaccuracy double precision, age double precision, accessioncode character varying(255), CONSTRAINT stem_pkey PRIMARY KEY (stem_id ), CONSTRAINT stem_individualplant_id FOREIGN KEY (individualplant_id) REFERENCES individualplant (individualplant_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT stem_keys UNIQUE (individualplant_id , sourceid ) ); CREATE TABLE specimen -- A herbarium specimen. Contains Darwin Core specimen data. ( specimen_id int(11) NOT NULL AUTO_INCREMENT, individualplant_id int(11), reference_id int(11) NOT NULL, collectioncode_dwc character varying(255), catalognumber_dwc character varying(255), collectiondate timestamp, collector_id int(11), museum_id int(11), sourceaccessionnumber character varying(100), accessioncode character varying(255), taxonoccurrence_id int(11), CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id ), CONSTRAINT specimen_collector_id FOREIGN KEY (collector_id) REFERENCES party (party_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT specimen_individualplant_id_fkey FOREIGN KEY (individualplant_id) REFERENCES individualplant (individualplant_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT specimen_museum_id FOREIGN KEY (museum_id) REFERENCES party (party_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT specimen_reference_id_fkey FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT specimen_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id) REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT specimen_keys UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ) ); CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table. ( taxondetermination_id int(11) NOT NULL AUTO_INCREMENT, taxonoccurrence_id int(11) NOT NULL, plantconcept_id int(11) NOT NULL, party_id int(11) NOT NULL, role_id int(11) NOT NULL, determinationtype character varying(30), reference_id int(11), originaldetermination int(1) NOT NULL, currentdetermination int(1) NOT NULL, taxonfit character varying(50), taxonconfidence character varying(50), grouptype character varying(20), notes text, notespublic int(1), notesmgt int(1), revisions int(1), determinationdate timestamp NOT NULL, emb_taxondetermination int(11), accessioncode character varying(255), CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ), CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id) REFERENCES party (party_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id) REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id) REFERENCES reference (reference_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id) REFERENCES aux_role (role_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id) REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE ); CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms. ( sizeclass_id int(11) NOT NULL AUTO_INCREMENT, mindiameter double precision, diameteraccuracy double precision, minheight double precision, heightaccuracy double precision, maxdiameter double precision, maxheight double precision, accessioncode character varying(255), CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id ) ); CREATE TABLE taxonbin -- Defines a set of aggregate measurements. Used by aggregateoccurrence to define how measurements were aggregated. ( taxonbin_id int(11) NOT NULL, label character varying(255) NOT NULL, stratum_id int(11), sizeclass_id int(11), coverindex_id int(11), accessioncode character varying(255), CONSTRAINT taxonbin_pkey PRIMARY KEY (taxonbin_id ), CONSTRAINT taxonbin_sizeclass_id FOREIGN KEY (sizeclass_id) REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE ON UPDATE CASCADE ON DELETE CASCADE );