Project

General

Profile

1 537 aaronmk
-- Existing tables
2
3 596 aaronmk
CREATE TABLE role
4 537 aaronmk
(
5
  role_id serial NOT NULL,
6
  rolecode character varying(30) NOT NULL,
7
  roledescription character varying(200),
8 596 aaronmk
  CONSTRAINT role_pkey PRIMARY KEY (role_id )
9 537 aaronmk
);
10
11
CREATE TABLE reference
12
(
13
  reference_id serial NOT NULL,
14
  shortname character varying(250),
15
  fulltext text,
16
  referencetype character varying(250)
17
);
18
19
CREATE TABLE party
20
(
21
  party_id serial NOT NULL,
22
  salutation character varying(20),
23
  givenname character varying(50),
24
  middlename character varying(50),
25
  surname character varying(50),
26
  organizationname character varying(100)
27
);
28
29
CREATE TABLE plantname
30
(
31
  plantname_id serial NOT NULL,
32
  plantname character varying(255) NOT NULL,
33
  reference_id integer,
34
  dateentered timestamp with time zone DEFAULT now(),
35
  CONSTRAINT plantname_pkey PRIMARY KEY (plantname_id ),
36
  CONSTRAINT plantname_reference_id FOREIGN KEY (reference_id)
37
      REFERENCES reference (reference_id) MATCH SIMPLE
38
      ON UPDATE CASCADE ON DELETE CASCADE
39
);
40
41
CREATE TABLE plantconcept
42
(
43
  plantconcept_id serial NOT NULL,
44
  plantname_id integer NOT NULL,
45 599 aaronmk
  reference_id integer,
46 537 aaronmk
  plantcode character varying(23),
47
  plantdescription text,
48
  d_obscount integer,
49
  d_currentaccepted boolean,
50
  accessioncode character varying(255),
51
  CONSTRAINT plantconcept_pkey PRIMARY KEY (plantconcept_id ),
52
  CONSTRAINT plantconcept_plantname_id FOREIGN KEY (plantname_id)
53
      REFERENCES plantname (plantname_id) MATCH SIMPLE
54
      ON UPDATE CASCADE ON DELETE CASCADE,
55
  CONSTRAINT plantconcept_reference_id FOREIGN KEY (reference_id)
56
      REFERENCES reference (reference_id) MATCH SIMPLE
57
      ON UPDATE CASCADE ON DELETE CASCADE
58
);
59
60 592 aaronmk
CREATE TABLE stratummethod
61
(
62
  stratummethod_id serial NOT NULL,
63
  reference_id integer,
64
  stratummethodname character varying(30) NOT NULL,
65
  stratummethoddescription text,
66
  stratumassignment character varying(50),
67
  accessioncode character varying(255),
68
  CONSTRAINT stratummethod_pkey PRIMARY KEY (stratummethod_id ),
69
  CONSTRAINT stratummethod_reference_id FOREIGN KEY (reference_id)
70
      REFERENCES reference (reference_id) MATCH SIMPLE
71
      ON UPDATE CASCADE ON DELETE CASCADE
72
);
73
74
CREATE TABLE stratumtype
75
(
76
  stratumtype_id serial NOT NULL,
77
  stratummethod_id integer NOT NULL,
78
  stratumindex character varying(10),
79
  stratumname character varying(30),
80
  stratumdescription text,
81
  CONSTRAINT stratumtype_pkey PRIMARY KEY (stratumtype_id ),
82
  CONSTRAINT stratumtype_stratummethod_id FOREIGN KEY (stratummethod_id)
83
      REFERENCES stratummethod (stratummethod_id) MATCH SIMPLE
84
      ON UPDATE CASCADE ON DELETE CASCADE
85
);
86
87 537 aaronmk
CREATE TABLE namedplace
88
(
89
  namedplace_id serial NOT NULL,
90
  placesystem character varying(50),
91
  placename character varying(100) NOT NULL,
92
  placedescription text,
93
  placecode character varying(15),
94
  owner character varying(100),
95
  reference_id integer,
96
  d_obscount integer,
97
  accessioncode character varying(255),
98
  CONSTRAINT namedplace_pkey PRIMARY KEY (namedplace_id ),
99
  CONSTRAINT namedplace_reference_id FOREIGN KEY (reference_id)
100
      REFERENCES reference (reference_id) MATCH SIMPLE
101
      ON UPDATE CASCADE ON DELETE CASCADE,
102
  CONSTRAINT namedplace_keys UNIQUE (placesystem , placename )
103
);
104
105 566 aaronmk
CREATE TABLE locationplace
106 552 aaronmk
(
107
  locationplace_id serial NOT NULL,
108
  location_id integer NOT NULL,
109
  calculated boolean,
110
  namedplace_id integer NOT NULL,
111 566 aaronmk
  CONSTRAINT locationplace_pkey PRIMARY KEY (locationplace_id ),
112
  CONSTRAINT locationplace_location_id FOREIGN KEY (location_id)
113 552 aaronmk
      REFERENCES location (location_id) MATCH SIMPLE
114
      ON UPDATE CASCADE ON DELETE CASCADE,
115 566 aaronmk
  CONSTRAINT locationplace_namedplace_id FOREIGN KEY (namedplace_id)
116 552 aaronmk
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
117
      ON UPDATE CASCADE ON DELETE CASCADE,
118 566 aaronmk
  CONSTRAINT locationplace_keys UNIQUE (location_id , namedplace_id )
119 552 aaronmk
);
120
121 537 aaronmk
CREATE TABLE project
122
(
123
  project_id serial NOT NULL,
124
  projectname character varying(150) NOT NULL,
125
  projectdescription text,
126
  startdate timestamp with time zone,
127
  stopdate timestamp with time zone,
128
  d_obscount integer,
129
  d_lastlocationaddeddate timestamp with time zone,
130
  accessioncode character varying(255),
131
  CONSTRAINT project_pkey PRIMARY KEY (project_id ),
132
  CONSTRAINT project_keys UNIQUE (projectname , startdate , stopdate )
133
);
134
135
-- New tables
136
137 535 aaronmk
CREATE TABLE location
138
(
139
  location_id serial NOT NULL,
140 582 aaronmk
  authorlocationcode character varying(30),
141 535 aaronmk
  reference_id integer,
142
  parent_id integer,
143 582 aaronmk
  reallatitude double precision,
144
  reallongitude double precision,
145 535 aaronmk
  locationaccuracy double precision,
146 575 aaronmk
  confidentialitystatus integer NOT NULL DEFAULT 0,
147 535 aaronmk
  confidentialityreason character varying(200),
148 580 aaronmk
  publiclatitude double precision,
149
  publiclongitude double precision,
150 561 aaronmk
  "... (truncated) ..." integer,
151 535 aaronmk
  accessioncode character varying(255),
152
  sublocationxposition double precision,
153
  sublocationyposition double precision,
154
  namedplace_id integer,
155
  CONSTRAINT location_pkey PRIMARY KEY (location_id ),
156
  CONSTRAINT location_namedplace_id FOREIGN KEY (namedplace_id)
157
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
158
      ON UPDATE CASCADE ON DELETE CASCADE,
159
  CONSTRAINT location_parent_id FOREIGN KEY (parent_id)
160
      REFERENCES location (location_id) MATCH SIMPLE
161
      ON UPDATE CASCADE ON DELETE CASCADE,
162
  CONSTRAINT location_reference_id FOREIGN KEY (reference_id)
163
      REFERENCES reference (reference_id) MATCH SIMPLE
164
      ON UPDATE CASCADE ON DELETE CASCADE,
165 582 aaronmk
  CONSTRAINT location_keys_code UNIQUE (reference_id , authorlocationcode ),
166
  CONSTRAINT location_keys_coords UNIQUE (reference_id , reallatitude , reallongitude ),
167
  CONSTRAINT location_keys_subplot_code UNIQUE (parent_id , authorlocationcode ),
168
  CONSTRAINT location_keys_subplot_coords UNIQUE (parent_id , sublocationxposition , sublocationyposition )
169 535 aaronmk
);
170
171
CREATE TABLE locationevent -- VegBank's observation table.
172
(
173
  locationevent_id serial NOT NULL,
174
  previous_id integer,
175 605 aaronmk
  location_id integer,
176 535 aaronmk
  project_id integer,
177 570 aaronmk
  authoreventcode character varying(30),
178 561 aaronmk
  "... (truncated) ..." integer,
179 535 aaronmk
  accessioncode character varying(255),
180 586 aaronmk
  sourceaccessioncode character varying(100),
181 535 aaronmk
  CONSTRAINT locationevent_pkey PRIMARY KEY (locationevent_id ),
182
  CONSTRAINT locationevent_location_id FOREIGN KEY (location_id)
183
      REFERENCES location (location_id) MATCH SIMPLE
184
      ON UPDATE CASCADE ON DELETE CASCADE,
185
  CONSTRAINT locationevent_project_id FOREIGN KEY (project_id)
186
      REFERENCES project (project_id) MATCH SIMPLE
187
      ON UPDATE CASCADE ON DELETE CASCADE,
188 586 aaronmk
  CONSTRAINT locationevent_keys_accessioncode UNIQUE (location_id , project_id , sourceaccessioncode ),
189
  CONSTRAINT locationevent_keys_code UNIQUE (location_id , project_id , authoreventcode )
190 535 aaronmk
);
191
192
CREATE TABLE taxonoccurrence -- VegBank's taxonobservation table.
193
(
194
  taxonoccurrence_id serial NOT NULL,
195 605 aaronmk
  locationevent_id integer,
196 535 aaronmk
  authorplantname character varying(255),
197
  reference_id integer,
198
  taxoninferencearea double precision,
199
  emb_taxonoccurrence integer,
200 561 aaronmk
  "... (truncated) ..." integer,
201 535 aaronmk
  accessioncode character varying(255),
202
  CONSTRAINT taxonoccurrence_pkey PRIMARY KEY (taxonoccurrence_id ),
203
  CONSTRAINT taxonoccurrence_locationevent_id FOREIGN KEY (locationevent_id)
204
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
205
      ON UPDATE CASCADE ON DELETE CASCADE,
206
  CONSTRAINT taxonoccurrence_reference_id FOREIGN KEY (reference_id)
207
      REFERENCES reference (reference_id) MATCH SIMPLE
208
      ON UPDATE CASCADE ON DELETE CASCADE
209
);
210
211
CREATE TABLE aggregateoccurrence -- VegBank's taxonimportance table.
212
(
213
  aggregateoccurrence_id serial NOT NULL,
214
  taxonoccurrence_id integer NOT NULL,
215
  cover double precision,
216
  basalarea double precision,
217
  biomass double precision,
218
  inferencearea double precision,
219
  stratumbase double precision,
220
  stratumheight double precision,
221
  emb_aggregateoccurrence integer,
222
  covercode character varying(10),
223 607 aaronmk
  count integer,
224 535 aaronmk
  accessioncode character varying(255),
225 586 aaronmk
  sourceaccessioncode character varying(100),
226 671 aaronmk
  plantobservation_id integer,
227 677 aaronmk
  stratum_id integer,
228 678 aaronmk
  sizeclass_id integer,
229
  coverindex_id integer,
230 535 aaronmk
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
231 671 aaronmk
  CONSTRAINT aggregateoccurrence_plantobservation_id FOREIGN KEY (plantobservation_id)
232
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
233 666 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
234 678 aaronmk
  CONSTRAINT aggregateoccurrence_sizeclass_id FOREIGN KEY (sizeclass_id)
235
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
236
      ON UPDATE CASCADE ON DELETE CASCADE,
237 677 aaronmk
  CONSTRAINT aggregateoccurrence_stratum_id FOREIGN KEY (stratum_id)
238
      REFERENCES stratum (stratum_id) MATCH SIMPLE
239
      ON UPDATE CASCADE ON DELETE CASCADE,
240 535 aaronmk
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
241
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
242
      ON UPDATE CASCADE ON DELETE CASCADE,
243 679 aaronmk
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode )
244 535 aaronmk
);
245
246 674 aaronmk
CREATE TABLE planttag
247
(
248
  planttag_id serial NOT NULL,
249 684 aaronmk
  plantobservation_id integer NOT NULL,
250 674 aaronmk
  tag character varying(255) NOT NULL,
251 684 aaronmk
  iscurrent boolean NOT NULL DEFAULT true,
252 674 aaronmk
  CONSTRAINT planttag_pkey PRIMARY KEY (planttag_id ),
253 684 aaronmk
  CONSTRAINT planttag_plantobservation_id FOREIGN KEY (plantobservation_id)
254
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
255 674 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
256 684 aaronmk
  CONSTRAINT planttag_current_unique UNIQUE (plantobservation_id , iscurrent ),
257
  CONSTRAINT planttag_keys UNIQUE (plantobservation_id , tag )
258 674 aaronmk
);
259
260 684 aaronmk
CREATE TABLE plant -- A physical, tagged plant.
261
(
262
  plant_id serial NOT NULL,
263
  CONSTRAINT plant_pkey PRIMARY KEY (plant_id )
264
);
265
266 671 aaronmk
CREATE TABLE plantobservation -- VegBank's stemcount table.
267 535 aaronmk
(
268 671 aaronmk
  plantobservation_id serial NOT NULL,
269 563 aaronmk
  overallheight double precision,
270
  overallheightaccuracy double precision,
271 671 aaronmk
  emb_plantobservation integer,
272 570 aaronmk
  authorplantcode character varying(20),
273 535 aaronmk
  accessioncode character varying(255),
274
  stemcount integer,
275 586 aaronmk
  sourceaccessioncode character varying(100),
276 674 aaronmk
  plant_id integer,
277 671 aaronmk
  CONSTRAINT plantobservation_pkey PRIMARY KEY (plantobservation_id ),
278 674 aaronmk
  CONSTRAINT plantobservation_plant_id FOREIGN KEY (plant_id)
279
      REFERENCES plant (plant_id) MATCH SIMPLE
280 682 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE
281 535 aaronmk
);
282
283 673 aaronmk
CREATE TABLE stemobservation -- VegBank's stemlocation table.
284 535 aaronmk
(
285 673 aaronmk
  stemobservation_id serial NOT NULL,
286 671 aaronmk
  plantobservation_id integer NOT NULL,
287 570 aaronmk
  authorstemcode character varying(20),
288 535 aaronmk
  xposition double precision,
289
  yposition double precision,
290
  health character varying(50),
291 673 aaronmk
  emb_stemobservation integer,
292 535 aaronmk
  diameter double precision,
293
  height double precision,
294
  heightaccuracy double precision,
295
  age double precision,
296
  accessioncode character varying(255),
297 556 aaronmk
  diameteraccuracy double precision,
298 586 aaronmk
  sourceaccessioncode character varying(100),
299 673 aaronmk
  CONSTRAINT stemobservation_pkey PRIMARY KEY (stemobservation_id ),
300
  CONSTRAINT stemobservation_plantobservation_id FOREIGN KEY (plantobservation_id)
301 671 aaronmk
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
302 535 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
303 673 aaronmk
  CONSTRAINT stemobservation_keys_accessioncode UNIQUE (plantobservation_id , sourceaccessioncode ),
304
  CONSTRAINT stemobservation_keys_code UNIQUE (plantobservation_id , authorstemcode )
305 535 aaronmk
);
306
307 670 aaronmk
CREATE TABLE specimen -- A physical specimen collected from a plant. Used to link replicates of the same specimen together.
308 669 aaronmk
(
309
  specimen_id serial NOT NULL,
310
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id )
311
);
312
313 670 aaronmk
CREATE TABLE specimenreplicate -- A herbarium's replicate of a specimen. Contains Darwin Core specimen data.
314 537 aaronmk
(
315 668 aaronmk
  specimenreplicate_id serial NOT NULL,
316 537 aaronmk
  reference_id integer NOT NULL,
317 668 aaronmk
  collectioncode_dwc character varying(255), -- The code for the collection that the specimenreplicate is from.
318 537 aaronmk
  catalognumber_dwc character varying(255),
319
  collectiondate timestamp with time zone,
320
  museum_id integer,
321 586 aaronmk
  sourceaccessioncode character varying(100),
322 537 aaronmk
  accessioncode character varying(255),
323 576 aaronmk
  taxonoccurrence_id integer NOT NULL,
324 613 aaronmk
  verbatimcollectorname character varying(255),
325 668 aaronmk
  collectionnumber character varying(255), -- The number of the specimenreplicate within the collection.
326 669 aaronmk
  specimen_id integer,
327 668 aaronmk
  CONSTRAINT specimenreplicate_pkey PRIMARY KEY (specimenreplicate_id ),
328
  CONSTRAINT specimenreplicate_museum_id FOREIGN KEY (museum_id)
329 537 aaronmk
      REFERENCES party (party_id) MATCH SIMPLE
330
      ON UPDATE CASCADE ON DELETE CASCADE,
331 668 aaronmk
  CONSTRAINT specimenreplicate_reference_id_fkey FOREIGN KEY (reference_id)
332 537 aaronmk
      REFERENCES reference (reference_id) MATCH SIMPLE
333
      ON UPDATE CASCADE ON DELETE CASCADE,
334 669 aaronmk
  CONSTRAINT specimenreplicate_specimen_id FOREIGN KEY (specimen_id)
335
      REFERENCES specimen (specimen_id) MATCH SIMPLE
336
      ON UPDATE CASCADE ON DELETE CASCADE,
337 668 aaronmk
  CONSTRAINT specimenreplicate_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
338 537 aaronmk
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
339
      ON UPDATE CASCADE ON DELETE CASCADE,
340 668 aaronmk
  CONSTRAINT specimenreplicate_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
341
  CONSTRAINT specimenreplicate_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ),
342 672 aaronmk
  CONSTRAINT specimenreplicate_keys_collectionnumber UNIQUE (reference_id , collectioncode_dwc , collectionnumber )
343 537 aaronmk
);
344
345 544 aaronmk
CREATE TABLE voucher
346
(
347
  voucher_id serial NOT NULL,
348 545 aaronmk
  taxonoccurrence_id integer NOT NULL,
349 668 aaronmk
  specimenreplicate_id integer NOT NULL,
350 544 aaronmk
  accessioncode character varying(255),
351
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
352 668 aaronmk
  CONSTRAINT voucher_specimenreplicate_id FOREIGN KEY (specimenreplicate_id)
353
      REFERENCES specimenreplicate (specimenreplicate_id) MATCH SIMPLE
354 544 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
355
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
356
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
357
      ON UPDATE CASCADE ON DELETE CASCADE,
358 668 aaronmk
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimenreplicate_id )
359 544 aaronmk
);
360
361 535 aaronmk
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
362
(
363
  taxondetermination_id serial NOT NULL,
364
  taxonoccurrence_id integer NOT NULL,
365
  plantconcept_id integer NOT NULL,
366 575 aaronmk
  party_id integer,
367 535 aaronmk
  role_id integer NOT NULL,
368
  determinationtype character varying(30),
369
  reference_id integer,
370 632 aaronmk
  isoriginal boolean NOT NULL DEFAULT false,
371
  iscurrent boolean NOT NULL DEFAULT false,
372 535 aaronmk
  taxonfit character varying(50),
373
  taxonconfidence character varying(50),
374
  grouptype character varying(20),
375
  notes text,
376
  notespublic boolean,
377
  notesmgt boolean,
378
  revisions boolean,
379 591 aaronmk
  determinationdate timestamp with time zone,
380 535 aaronmk
  emb_taxondetermination integer,
381
  accessioncode character varying(255),
382
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
383
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
384
      REFERENCES party (party_id) MATCH SIMPLE
385
      ON UPDATE CASCADE ON DELETE CASCADE,
386
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
387
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
388
      ON UPDATE CASCADE ON DELETE CASCADE,
389
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
390
      REFERENCES reference (reference_id) MATCH SIMPLE
391
      ON UPDATE CASCADE ON DELETE CASCADE,
392
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
393 596 aaronmk
      REFERENCES role (role_id) MATCH SIMPLE
394 535 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
395
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
396
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
397
      ON UPDATE CASCADE ON DELETE CASCADE
398
);
399
400 552 aaronmk
CREATE TABLE stratum
401
(
402
  stratum_id serial NOT NULL,
403
  locationevent_id integer NOT NULL,
404
  stratumtype_id integer NOT NULL,
405
  stratumheight double precision,
406
  stratumbase double precision,
407
  stratumcover double precision,
408 676 aaronmk
  area double precision,
409 552 aaronmk
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
410
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
411
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
412 592 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
413
  CONSTRAINT stratum_stratumtype_id FOREIGN KEY (stratumtype_id)
414
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
415 559 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE
416 552 aaronmk
);
417
418 537 aaronmk
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
419 535 aaronmk
(
420 537 aaronmk
  sizeclass_id serial NOT NULL,
421
  mindiameter double precision,
422
  minheight double precision,
423
  maxdiameter double precision,
424
  maxheight double precision,
425 535 aaronmk
  accessioncode character varying(255),
426 537 aaronmk
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
427 535 aaronmk
);