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 584 aaronmk
  taxonbinmethod_id integer,
216 535 aaronmk
  cover double precision,
217
  basalarea double precision,
218
  biomass double precision,
219
  inferencearea double precision,
220
  stratumbase double precision,
221
  stratumheight double precision,
222
  emb_aggregateoccurrence integer,
223
  covercode character varying(10),
224 607 aaronmk
  count integer,
225 535 aaronmk
  accessioncode character varying(255),
226 586 aaronmk
  sourceaccessioncode character varying(100),
227 535 aaronmk
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
228 584 aaronmk
  CONSTRAINT aggregateoccurrence_taxonbinmethod_id FOREIGN KEY (taxonbinmethod_id)
229
      REFERENCES taxonbinmethod (taxonbinmethod_id) MATCH SIMPLE
230 535 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
231
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
232
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
233
      ON UPDATE CASCADE ON DELETE CASCADE,
234 586 aaronmk
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode ),
235
  CONSTRAINT aggregateoccurrence_keys_method UNIQUE (taxonoccurrence_id , taxonbinmethod_id )
236 535 aaronmk
);
237
238
CREATE TABLE individualplant -- VegBank's stemcount table.
239
(
240
  individualplant_id serial NOT NULL,
241
  aggregateoccurrence_id integer NOT NULL,
242 563 aaronmk
  overallheight double precision,
243
  overallheightaccuracy double precision,
244 535 aaronmk
  emb_individualplant integer,
245 570 aaronmk
  authorplantcode character varying(20),
246 535 aaronmk
  accessioncode character varying(255),
247
  stemcount integer,
248 586 aaronmk
  sourceaccessioncode character varying(100),
249 535 aaronmk
  CONSTRAINT individualplant_pkey PRIMARY KEY (individualplant_id ),
250
  CONSTRAINT individualplant_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id)
251
      REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE
252
      ON UPDATE CASCADE ON DELETE CASCADE,
253 586 aaronmk
  CONSTRAINT individualplant_keys_accessioncode UNIQUE (aggregateoccurrence_id , sourceaccessioncode ),
254
  CONSTRAINT individualplant_keys_code UNIQUE (aggregateoccurrence_id , authorplantcode )
255 535 aaronmk
);
256
257
CREATE TABLE stem -- VegBank's stemlocation table.
258
(
259
  stem_id serial NOT NULL,
260
  individualplant_id integer NOT NULL,
261 570 aaronmk
  authorstemcode character varying(20),
262 535 aaronmk
  xposition double precision,
263
  yposition double precision,
264
  health character varying(50),
265
  emb_stem integer,
266
  diameter double precision,
267
  height double precision,
268
  heightaccuracy double precision,
269
  age double precision,
270
  accessioncode character varying(255),
271 556 aaronmk
  diameteraccuracy double precision,
272 586 aaronmk
  sourceaccessioncode character varying(100),
273 535 aaronmk
  CONSTRAINT stem_pkey PRIMARY KEY (stem_id ),
274
  CONSTRAINT stem_individualplant_id FOREIGN KEY (individualplant_id)
275
      REFERENCES individualplant (individualplant_id) MATCH SIMPLE
276
      ON UPDATE CASCADE ON DELETE CASCADE,
277 586 aaronmk
  CONSTRAINT stem_keys_accessioncode UNIQUE (individualplant_id , sourceaccessioncode ),
278
  CONSTRAINT stem_keys_code UNIQUE (individualplant_id , authorstemcode )
279 535 aaronmk
);
280
281 537 aaronmk
CREATE TABLE specimen -- A herbarium specimen. Contains Darwin Core specimen data.
282
(
283
  specimen_id serial NOT NULL,
284
  reference_id integer NOT NULL,
285
  collectioncode_dwc character varying(255),
286
  catalognumber_dwc character varying(255),
287
  collectiondate timestamp with time zone,
288
  collector_id integer,
289
  museum_id integer,
290 586 aaronmk
  sourceaccessioncode character varying(100),
291 537 aaronmk
  accessioncode character varying(255),
292 576 aaronmk
  taxonoccurrence_id integer NOT NULL,
293 572 aaronmk
  collectornumber_dwc character varying(255),
294 589 aaronmk
  authorspecimencode character varying(20),
295 537 aaronmk
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id ),
296
  CONSTRAINT specimen_collector_id FOREIGN KEY (collector_id)
297
      REFERENCES party (party_id) MATCH SIMPLE
298
      ON UPDATE CASCADE ON DELETE CASCADE,
299
  CONSTRAINT specimen_museum_id FOREIGN KEY (museum_id)
300
      REFERENCES party (party_id) MATCH SIMPLE
301
      ON UPDATE CASCADE ON DELETE CASCADE,
302
  CONSTRAINT specimen_reference_id_fkey FOREIGN KEY (reference_id)
303
      REFERENCES reference (reference_id) MATCH SIMPLE
304
      ON UPDATE CASCADE ON DELETE CASCADE,
305
  CONSTRAINT specimen_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
306
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
307
      ON UPDATE CASCADE ON DELETE CASCADE,
308 586 aaronmk
  CONSTRAINT specimen_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
309 589 aaronmk
  CONSTRAINT specimen_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ),
310
  CONSTRAINT specimen_keys_code UNIQUE (reference_id , collectioncode_dwc , authorspecimencode )
311 537 aaronmk
);
312
313 544 aaronmk
CREATE TABLE voucher
314
(
315
  voucher_id serial NOT NULL,
316 545 aaronmk
  taxonoccurrence_id integer NOT NULL,
317
  specimen_id integer NOT NULL,
318 544 aaronmk
  accessioncode character varying(255),
319
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
320
  CONSTRAINT voucher_specimen_id FOREIGN KEY (specimen_id)
321
      REFERENCES specimen (specimen_id) MATCH SIMPLE
322
      ON UPDATE CASCADE ON DELETE CASCADE,
323
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
324
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
325
      ON UPDATE CASCADE ON DELETE CASCADE,
326
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimen_id )
327
);
328
329 535 aaronmk
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
330
(
331
  taxondetermination_id serial NOT NULL,
332
  taxonoccurrence_id integer NOT NULL,
333
  plantconcept_id integer NOT NULL,
334 575 aaronmk
  party_id integer,
335 535 aaronmk
  role_id integer NOT NULL,
336
  determinationtype character varying(30),
337
  reference_id integer,
338 575 aaronmk
  originaldetermination boolean NOT NULL DEFAULT false,
339
  currentdetermination boolean NOT NULL DEFAULT false,
340 535 aaronmk
  taxonfit character varying(50),
341
  taxonconfidence character varying(50),
342
  grouptype character varying(20),
343
  notes text,
344
  notespublic boolean,
345
  notesmgt boolean,
346
  revisions boolean,
347 591 aaronmk
  determinationdate timestamp with time zone,
348 535 aaronmk
  emb_taxondetermination integer,
349
  accessioncode character varying(255),
350
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
351
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
352
      REFERENCES party (party_id) MATCH SIMPLE
353
      ON UPDATE CASCADE ON DELETE CASCADE,
354
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
355
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
356
      ON UPDATE CASCADE ON DELETE CASCADE,
357
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
358
      REFERENCES reference (reference_id) MATCH SIMPLE
359
      ON UPDATE CASCADE ON DELETE CASCADE,
360
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
361 596 aaronmk
      REFERENCES role (role_id) MATCH SIMPLE
362 535 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
363
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
364
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
365
      ON UPDATE CASCADE ON DELETE CASCADE
366
);
367
368 552 aaronmk
CREATE TABLE stratum
369
(
370
  stratum_id serial NOT NULL,
371
  locationevent_id integer NOT NULL,
372
  stratumtype_id integer NOT NULL,
373
  stratummethod_id integer,
374
  stratumname character varying(30),
375
  stratumheight double precision,
376
  stratumbase double precision,
377
  stratumcover double precision,
378
  stratumdescription character varying(200),
379
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
380
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
381
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
382 592 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
383
  CONSTRAINT stratum_stratumtype_id FOREIGN KEY (stratumtype_id)
384
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
385 559 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE
386 552 aaronmk
);
387
388 537 aaronmk
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
389 535 aaronmk
(
390 537 aaronmk
  sizeclass_id serial NOT NULL,
391
  mindiameter double precision,
392
  minheight double precision,
393
  maxdiameter double precision,
394
  maxheight double precision,
395 535 aaronmk
  accessioncode character varying(255),
396 537 aaronmk
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
397 535 aaronmk
);
398
399 592 aaronmk
CREATE TABLE taxonbinmethod
400 535 aaronmk
(
401 584 aaronmk
  taxonbinmethod_id integer NOT NULL,
402 592 aaronmk
  label character varying(255),
403
  stratumtype_id integer,
404 535 aaronmk
  sizeclass_id integer,
405
  coverindex_id integer,
406
  accessioncode character varying(255),
407 584 aaronmk
  CONSTRAINT taxonbinmethod_pkey PRIMARY KEY (taxonbinmethod_id ),
408
  CONSTRAINT taxonbinmethod_sizeclass_id FOREIGN KEY (sizeclass_id)
409 535 aaronmk
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
410 583 aaronmk
      ON UPDATE CASCADE ON DELETE CASCADE,
411 592 aaronmk
  CONSTRAINT taxonbinmethod_stratumtype_id FOREIGN KEY (stratumtype_id)
412
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
413
      ON UPDATE CASCADE ON DELETE CASCADE
414 535 aaronmk
);