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
  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
  count integer,
224
  accessioncode character varying(255),
225
  sourceaccessioncode character varying(100),
226
  plantobservation_id integer,
227
  stratum_id integer,
228
  sizeclass_id integer,
229
  coverindex_id integer,
230
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
231
  CONSTRAINT aggregateoccurrence_plantobservation_id FOREIGN KEY (plantobservation_id)
232
      REFERENCES plantobservation (plantobservation_id) MATCH SIMPLE
233
      ON UPDATE CASCADE ON DELETE CASCADE,
234
  CONSTRAINT aggregateoccurrence_sizeclass_id FOREIGN KEY (sizeclass_id)
235
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
236
      ON UPDATE CASCADE ON DELETE CASCADE,
237
  CONSTRAINT aggregateoccurrence_stratum_id FOREIGN KEY (stratum_id)
238
      REFERENCES stratum (stratum_id) MATCH SIMPLE
239
      ON UPDATE CASCADE ON DELETE CASCADE,
240
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
241
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
242
      ON UPDATE CASCADE ON DELETE CASCADE,
243
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode )
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
  overallheight double precision,
268
  overallheightaccuracy double precision,
269
  emb_plantobservation integer,
270
  authorplantcode character varying(20),
271
  accessioncode character varying(255),
272
  stemcount integer,
273
  sourceaccessioncode character varying(100),
274
  plant_id integer,
275
  CONSTRAINT plantobservation_pkey PRIMARY KEY (plantobservation_id ),
276
  CONSTRAINT plantobservation_plant_id FOREIGN KEY (plant_id)
277
      REFERENCES plant (plant_id) MATCH SIMPLE
278
      ON UPDATE CASCADE ON DELETE CASCADE
279
);
280

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

    
305
CREATE TABLE specimen -- A physical specimen collected from a plant. Used to link replicates of the same specimen together.
306
(
307
  specimen_id serial NOT NULL,
308
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id )
309
);
310

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

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

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

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

    
416
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
417
(
418
  sizeclass_id serial NOT NULL,
419
  mindiameter double precision,
420
  minheight double precision,
421
  maxdiameter double precision,
422
  maxheight double precision,
423
  accessioncode character varying(255),
424
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
425
);
(8-8/12)