Project

General

Profile

1
-- Existing tables
2

    
3
CREATE TABLE role
4
(
5
  role_id serial NOT NULL,
6
  rolecode character varying(30) NOT NULL,
7
  roledescription character varying(200),
8
  CONSTRAINT role_pkey PRIMARY KEY (role_id )
9
);
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
  reference_id integer,
46
  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
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
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
CREATE TABLE locationplace
106
(
107
  locationplace_id serial NOT NULL,
108
  location_id integer NOT NULL,
109
  calculated boolean,
110
  namedplace_id integer NOT NULL,
111
  CONSTRAINT locationplace_pkey PRIMARY KEY (locationplace_id ),
112
  CONSTRAINT locationplace_location_id FOREIGN KEY (location_id)
113
      REFERENCES location (location_id) MATCH SIMPLE
114
      ON UPDATE CASCADE ON DELETE CASCADE,
115
  CONSTRAINT locationplace_namedplace_id FOREIGN KEY (namedplace_id)
116
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
117
      ON UPDATE CASCADE ON DELETE CASCADE,
118
  CONSTRAINT locationplace_keys UNIQUE (location_id , namedplace_id )
119
);
120

    
121
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
CREATE TABLE location
138
(
139
  location_id serial NOT NULL,
140
  authorlocationcode character varying(30),
141
  reference_id integer,
142
  parent_id integer,
143
  reallatitude double precision,
144
  reallongitude double precision,
145
  locationaccuracy double precision,
146
  confidentialitystatus integer NOT NULL DEFAULT 0,
147
  confidentialityreason character varying(200),
148
  publiclatitude double precision,
149
  publiclongitude double precision,
150
  "... (truncated) ..." integer,
151
  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
  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
);
170

    
171
CREATE TABLE locationevent -- VegBank's observation table.
172
(
173
  locationevent_id serial NOT NULL,
174
  previous_id integer,
175
  location_id integer,
176
  project_id integer,
177
  authoreventcode character varying(30),
178
  "... (truncated) ..." integer,
179
  accessioncode character varying(255),
180
  sourceaccessioncode character varying(100),
181
  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
  CONSTRAINT locationevent_keys_accessioncode UNIQUE (location_id , project_id , sourceaccessioncode ),
189
  CONSTRAINT locationevent_keys_code UNIQUE (location_id , project_id , authoreventcode )
190
);
191

    
192
CREATE TABLE taxonoccurrence -- VegBank's taxonobservation table.
193
(
194
  taxonoccurrence_id serial NOT NULL,
195
  locationevent_id integer,
196
  authorplantname character varying(255),
197
  reference_id integer,
198
  taxoninferencearea double precision,
199
  emb_taxonoccurrence integer,
200
  "... (truncated) ..." integer,
201
  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
  taxonbinmethod_id integer,
216
  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
  count integer,
225
  accessioncode character varying(255),
226
  sourceaccessioncode character varying(100),
227
  plantobservation_id integer,
228
  stratum_id integer,
229
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
230
  CONSTRAINT aggregateoccurrence_plantobservation_id FOREIGN KEY (plantobservation_id)
231
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
232
      ON UPDATE CASCADE ON DELETE CASCADE,
233
  CONSTRAINT aggregateoccurrence_stratum_id FOREIGN KEY (stratum_id)
234
      REFERENCES stratum (stratum_id) MATCH SIMPLE
235
      ON UPDATE CASCADE ON DELETE CASCADE,
236
  CONSTRAINT aggregateoccurrence_taxonbinmethod_id FOREIGN KEY (taxonbinmethod_id)
237
      REFERENCES taxonbinmethod (taxonbinmethod_id) MATCH SIMPLE
238
      ON UPDATE CASCADE ON DELETE CASCADE,
239
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
240
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
241
      ON UPDATE CASCADE ON DELETE CASCADE,
242
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode ),
243
  CONSTRAINT aggregateoccurrence_keys_method UNIQUE (taxonoccurrence_id , taxonbinmethod_id )
244
);
245

    
246
CREATE TABLE plant -- A physical, tagged plant.
247
(
248
  plant_id serial NOT NULL,
249
  CONSTRAINT plant_pkey PRIMARY KEY (plant_id )
250
);
251

    
252
CREATE TABLE planttag
253
(
254
  planttag_id serial NOT NULL,
255
  plant_id integer NOT NULL,
256
  tag character varying(255) NOT NULL,
257
  CONSTRAINT planttag_pkey PRIMARY KEY (planttag_id ),
258
  CONSTRAINT planttag_plant_id FOREIGN KEY (plant_id)
259
      REFERENCES plant (plant_id) MATCH SIMPLE
260
      ON UPDATE CASCADE ON DELETE CASCADE,
261
  CONSTRAINT planttag_keys UNIQUE (plant_id , tag )
262
);
263

    
264
CREATE TABLE plantobservation -- VegBank's stemcount table.
265
(
266
  plantobservation_id serial NOT NULL,
267
  aggregateoccurrence_id integer NOT NULL,
268
  overallheight double precision,
269
  overallheightaccuracy double precision,
270
  emb_plantobservation integer,
271
  authorplantcode character varying(20),
272
  accessioncode character varying(255),
273
  stemcount integer,
274
  sourceaccessioncode character varying(100),
275
  plant_id integer,
276
  CONSTRAINT plantobservation_pkey PRIMARY KEY (plantobservation_id ),
277
  CONSTRAINT plantobservation_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id)
278
      REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE
279
      ON UPDATE CASCADE ON DELETE CASCADE,
280
  CONSTRAINT plantobservation_plant_id FOREIGN KEY (plant_id)
281
      REFERENCES plant (plant_id) MATCH SIMPLE
282
      ON UPDATE CASCADE ON DELETE CASCADE,
283
  CONSTRAINT plantobservation_aggregateoccurrence_id_1_to_1 UNIQUE (aggregateoccurrence_id )
284
);
285

    
286
CREATE TABLE stemobservation -- VegBank's stemlocation table.
287
(
288
  stemobservation_id serial NOT NULL,
289
  plantobservation_id integer NOT NULL,
290
  authorstemcode character varying(20),
291
  xposition double precision,
292
  yposition double precision,
293
  health character varying(50),
294
  emb_stemobservation integer,
295
  diameter double precision,
296
  height double precision,
297
  heightaccuracy double precision,
298
  age double precision,
299
  accessioncode character varying(255),
300
  diameteraccuracy double precision,
301
  sourceaccessioncode character varying(100),
302
  CONSTRAINT stemobservation_pkey PRIMARY KEY (stemobservation_id ),
303
  CONSTRAINT stemobservation_plantobservation_id FOREIGN KEY (plantobservation_id)
304
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
305
      ON UPDATE CASCADE ON DELETE CASCADE,
306
  CONSTRAINT stemobservation_keys_accessioncode UNIQUE (plantobservation_id , sourceaccessioncode ),
307
  CONSTRAINT stemobservation_keys_code UNIQUE (plantobservation_id , authorstemcode )
308
);
309

    
310
CREATE TABLE specimen -- A physical specimen collected from a plant. Used to link replicates of the same specimen together.
311
(
312
  specimen_id serial NOT NULL,
313
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id )
314
);
315

    
316
CREATE TABLE specimenreplicate -- A herbarium's replicate of a specimen. Contains Darwin Core specimen data.
317
(
318
  specimenreplicate_id serial NOT NULL,
319
  reference_id integer NOT NULL,
320
  collectioncode_dwc character varying(255), -- The code for the collection that the specimenreplicate is from.
321
  catalognumber_dwc character varying(255),
322
  collectiondate timestamp with time zone,
323
  museum_id integer,
324
  sourceaccessioncode character varying(100),
325
  accessioncode character varying(255),
326
  taxonoccurrence_id integer NOT NULL,
327
  verbatimcollectorname character varying(255),
328
  collectionnumber character varying(255), -- The number of the specimenreplicate within the collection.
329
  specimen_id integer,
330
  CONSTRAINT specimenreplicate_pkey PRIMARY KEY (specimenreplicate_id ),
331
  CONSTRAINT specimenreplicate_museum_id FOREIGN KEY (museum_id)
332
      REFERENCES party (party_id) MATCH SIMPLE
333
      ON UPDATE CASCADE ON DELETE CASCADE,
334
  CONSTRAINT specimenreplicate_reference_id_fkey FOREIGN KEY (reference_id)
335
      REFERENCES reference (reference_id) MATCH SIMPLE
336
      ON UPDATE CASCADE ON DELETE CASCADE,
337
  CONSTRAINT specimenreplicate_specimen_id FOREIGN KEY (specimen_id)
338
      REFERENCES specimen (specimen_id) MATCH SIMPLE
339
      ON UPDATE CASCADE ON DELETE CASCADE,
340
  CONSTRAINT specimenreplicate_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
341
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
342
      ON UPDATE CASCADE ON DELETE CASCADE,
343
  CONSTRAINT specimenreplicate_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
344
  CONSTRAINT specimenreplicate_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ),
345
  CONSTRAINT specimenreplicate_keys_collectionnumber UNIQUE (reference_id , collectioncode_dwc , collectionnumber )
346
);
347

    
348
CREATE TABLE voucher
349
(
350
  voucher_id serial NOT NULL,
351
  taxonoccurrence_id integer NOT NULL,
352
  specimenreplicate_id integer NOT NULL,
353
  accessioncode character varying(255),
354
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
355
  CONSTRAINT voucher_specimenreplicate_id FOREIGN KEY (specimenreplicate_id)
356
      REFERENCES specimenreplicate (specimenreplicate_id) MATCH SIMPLE
357
      ON UPDATE CASCADE ON DELETE CASCADE,
358
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
359
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
360
      ON UPDATE CASCADE ON DELETE CASCADE,
361
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimenreplicate_id )
362
);
363

    
364
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
365
(
366
  taxondetermination_id serial NOT NULL,
367
  taxonoccurrence_id integer NOT NULL,
368
  plantconcept_id integer NOT NULL,
369
  party_id integer,
370
  role_id integer NOT NULL,
371
  determinationtype character varying(30),
372
  reference_id integer,
373
  isoriginal boolean NOT NULL DEFAULT false,
374
  iscurrent boolean NOT NULL DEFAULT false,
375
  taxonfit character varying(50),
376
  taxonconfidence character varying(50),
377
  grouptype character varying(20),
378
  notes text,
379
  notespublic boolean,
380
  notesmgt boolean,
381
  revisions boolean,
382
  determinationdate timestamp with time zone,
383
  emb_taxondetermination integer,
384
  accessioncode character varying(255),
385
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
386
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
387
      REFERENCES party (party_id) MATCH SIMPLE
388
      ON UPDATE CASCADE ON DELETE CASCADE,
389
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
390
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
391
      ON UPDATE CASCADE ON DELETE CASCADE,
392
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
393
      REFERENCES reference (reference_id) MATCH SIMPLE
394
      ON UPDATE CASCADE ON DELETE CASCADE,
395
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
396
      REFERENCES role (role_id) MATCH SIMPLE
397
      ON UPDATE CASCADE ON DELETE CASCADE,
398
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
399
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
400
      ON UPDATE CASCADE ON DELETE CASCADE
401
);
402

    
403
CREATE TABLE stratum
404
(
405
  stratum_id serial NOT NULL,
406
  locationevent_id integer NOT NULL,
407
  stratumtype_id integer NOT NULL,
408
  stratumheight double precision,
409
  stratumbase double precision,
410
  stratumcover double precision,
411
  area double precision,
412
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
413
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
414
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
415
      ON UPDATE CASCADE ON DELETE CASCADE,
416
  CONSTRAINT stratum_stratumtype_id FOREIGN KEY (stratumtype_id)
417
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
418
      ON UPDATE CASCADE ON DELETE CASCADE
419
);
420

    
421
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
422
(
423
  sizeclass_id serial NOT NULL,
424
  mindiameter double precision,
425
  minheight double precision,
426
  maxdiameter double precision,
427
  maxheight double precision,
428
  accessioncode character varying(255),
429
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
430
);
431

    
432
CREATE TABLE taxonbinmethod
433
(
434
  taxonbinmethod_id integer NOT NULL,
435
  label character varying(255),
436
  stratumtype_id integer,
437
  sizeclass_id integer,
438
  coverindex_id integer,
439
  accessioncode character varying(255),
440
  CONSTRAINT taxonbinmethod_pkey PRIMARY KEY (taxonbinmethod_id ),
441
  CONSTRAINT taxonbinmethod_sizeclass_id FOREIGN KEY (sizeclass_id)
442
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
443
      ON UPDATE CASCADE ON DELETE CASCADE,
444
  CONSTRAINT taxonbinmethod_stratumtype_id FOREIGN KEY (stratumtype_id)
445
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
446
      ON UPDATE CASCADE ON DELETE CASCADE
447
);
(8-8/12)