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
  individualplant_id integer,
228
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
229
  CONSTRAINT aggregateoccurrence_individualplant_id FOREIGN KEY (individualplant_id)
230
      REFERENCES individualplant (individualplant_id) MATCH SIMPLE
231
      ON UPDATE CASCADE ON DELETE CASCADE,
232
  CONSTRAINT aggregateoccurrence_taxonbinmethod_id FOREIGN KEY (taxonbinmethod_id)
233
      REFERENCES taxonbinmethod (taxonbinmethod_id) MATCH SIMPLE
234
      ON UPDATE CASCADE ON DELETE CASCADE,
235
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
236
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
237
      ON UPDATE CASCADE ON DELETE CASCADE,
238
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode ),
239
  CONSTRAINT aggregateoccurrence_keys_method UNIQUE (taxonoccurrence_id , taxonbinmethod_id )
240
);
241

    
242
CREATE TABLE individualplant -- VegBank's stemcount table.
243
(
244
  individualplant_id serial NOT NULL,
245
  aggregateoccurrence_id integer NOT NULL,
246
  overallheight double precision,
247
  overallheightaccuracy double precision,
248
  emb_individualplant integer,
249
  authorplantcode character varying(20),
250
  accessioncode character varying(255),
251
  stemcount integer,
252
  sourceaccessioncode character varying(100),
253
  CONSTRAINT individualplant_pkey PRIMARY KEY (individualplant_id ),
254
  CONSTRAINT individualplant_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id)
255
      REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE
256
      ON UPDATE CASCADE ON DELETE CASCADE,
257
  CONSTRAINT individualplant_aggregateoccurrence_id_1_to_1 UNIQUE (aggregateoccurrence_id )
258
);
259

    
260
CREATE TABLE stem -- VegBank's stemlocation table.
261
(
262
  stem_id serial NOT NULL,
263
  individualplant_id integer NOT NULL,
264
  authorstemcode character varying(20),
265
  xposition double precision,
266
  yposition double precision,
267
  health character varying(50),
268
  emb_stem integer,
269
  diameter double precision,
270
  height double precision,
271
  heightaccuracy double precision,
272
  age double precision,
273
  accessioncode character varying(255),
274
  diameteraccuracy double precision,
275
  sourceaccessioncode character varying(100),
276
  CONSTRAINT stem_pkey PRIMARY KEY (stem_id ),
277
  CONSTRAINT stem_individualplant_id FOREIGN KEY (individualplant_id)
278
      REFERENCES individualplant (individualplant_id) MATCH SIMPLE
279
      ON UPDATE CASCADE ON DELETE CASCADE,
280
  CONSTRAINT stem_keys_accessioncode UNIQUE (individualplant_id , sourceaccessioncode ),
281
  CONSTRAINT stem_keys_code UNIQUE (individualplant_id , authorstemcode )
282
);
283

    
284
CREATE TABLE specimen -- A physical specimen collected from a plant. Used to link replicates of the same specimen together.
285
(
286
  specimen_id serial NOT NULL,
287
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id )
288
);
289

    
290
CREATE TABLE specimenreplicate -- A herbarium's replicate of a specimen. Contains Darwin Core specimen data.
291
(
292
  specimenreplicate_id serial NOT NULL,
293
  reference_id integer NOT NULL,
294
  collectioncode_dwc character varying(255), -- The code for the collection that the specimenreplicate is from.
295
  catalognumber_dwc character varying(255),
296
  collectiondate timestamp with time zone,
297
  museum_id integer,
298
  sourceaccessioncode character varying(100),
299
  accessioncode character varying(255),
300
  taxonoccurrence_id integer NOT NULL,
301
  verbatimcollectorname character varying(255),
302
  collectionnumber character varying(255), -- The number of the specimenreplicate within the collection.
303
  specimen_id integer,
304
  CONSTRAINT specimenreplicate_pkey PRIMARY KEY (specimenreplicate_id ),
305
  CONSTRAINT specimenreplicate_museum_id FOREIGN KEY (museum_id)
306
      REFERENCES party (party_id) MATCH SIMPLE
307
      ON UPDATE CASCADE ON DELETE CASCADE,
308
  CONSTRAINT specimenreplicate_reference_id_fkey FOREIGN KEY (reference_id)
309
      REFERENCES reference (reference_id) MATCH SIMPLE
310
      ON UPDATE CASCADE ON DELETE CASCADE,
311
  CONSTRAINT specimenreplicate_specimen_id FOREIGN KEY (specimen_id)
312
      REFERENCES specimen (specimen_id) MATCH SIMPLE
313
      ON UPDATE CASCADE ON DELETE CASCADE,
314
  CONSTRAINT specimenreplicate_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
315
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
316
      ON UPDATE CASCADE ON DELETE CASCADE,
317
  CONSTRAINT specimenreplicate_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
318
  CONSTRAINT specimenreplicate_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ),
319
  CONSTRAINT specimenreplicate_keys_collectionnumber UNIQUE (reference_id , collectioncode_dwc , collectionnumber ),
320
  CONSTRAINT specimenreplicate_taxonoccurrence_id_1_to_1 UNIQUE (taxonoccurrence_id )
321
);
322

    
323
CREATE TABLE voucher
324
(
325
  voucher_id serial NOT NULL,
326
  taxonoccurrence_id integer NOT NULL,
327
  specimenreplicate_id integer NOT NULL,
328
  accessioncode character varying(255),
329
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
330
  CONSTRAINT voucher_specimenreplicate_id FOREIGN KEY (specimenreplicate_id)
331
      REFERENCES specimenreplicate (specimenreplicate_id) MATCH SIMPLE
332
      ON UPDATE CASCADE ON DELETE CASCADE,
333
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
334
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
335
      ON UPDATE CASCADE ON DELETE CASCADE,
336
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimenreplicate_id )
337
);
338

    
339
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
340
(
341
  taxondetermination_id serial NOT NULL,
342
  taxonoccurrence_id integer NOT NULL,
343
  plantconcept_id integer NOT NULL,
344
  party_id integer,
345
  role_id integer NOT NULL,
346
  determinationtype character varying(30),
347
  reference_id integer,
348
  isoriginal boolean NOT NULL DEFAULT false,
349
  iscurrent boolean NOT NULL DEFAULT false,
350
  taxonfit character varying(50),
351
  taxonconfidence character varying(50),
352
  grouptype character varying(20),
353
  notes text,
354
  notespublic boolean,
355
  notesmgt boolean,
356
  revisions boolean,
357
  determinationdate timestamp with time zone,
358
  emb_taxondetermination integer,
359
  accessioncode character varying(255),
360
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
361
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
362
      REFERENCES party (party_id) MATCH SIMPLE
363
      ON UPDATE CASCADE ON DELETE CASCADE,
364
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
365
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
366
      ON UPDATE CASCADE ON DELETE CASCADE,
367
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
368
      REFERENCES reference (reference_id) MATCH SIMPLE
369
      ON UPDATE CASCADE ON DELETE CASCADE,
370
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
371
      REFERENCES role (role_id) MATCH SIMPLE
372
      ON UPDATE CASCADE ON DELETE CASCADE,
373
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
374
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
375
      ON UPDATE CASCADE ON DELETE CASCADE
376
);
377

    
378
CREATE TABLE stratum
379
(
380
  stratum_id serial NOT NULL,
381
  locationevent_id integer NOT NULL,
382
  stratumtype_id integer NOT NULL,
383
  stratummethod_id integer,
384
  stratumname character varying(30),
385
  stratumheight double precision,
386
  stratumbase double precision,
387
  stratumcover double precision,
388
  stratumdescription character varying(200),
389
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
390
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
391
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
392
      ON UPDATE CASCADE ON DELETE CASCADE,
393
  CONSTRAINT stratum_stratumtype_id FOREIGN KEY (stratumtype_id)
394
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
395
      ON UPDATE CASCADE ON DELETE CASCADE
396
);
397

    
398
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
399
(
400
  sizeclass_id serial NOT NULL,
401
  mindiameter double precision,
402
  minheight double precision,
403
  maxdiameter double precision,
404
  maxheight double precision,
405
  accessioncode character varying(255),
406
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
407
);
408

    
409
CREATE TABLE taxonbinmethod
410
(
411
  taxonbinmethod_id integer NOT NULL,
412
  label character varying(255),
413
  stratumtype_id integer,
414
  sizeclass_id integer,
415
  coverindex_id integer,
416
  accessioncode character varying(255),
417
  CONSTRAINT taxonbinmethod_pkey PRIMARY KEY (taxonbinmethod_id ),
418
  CONSTRAINT taxonbinmethod_sizeclass_id FOREIGN KEY (sizeclass_id)
419
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
420
      ON UPDATE CASCADE ON DELETE CASCADE,
421
  CONSTRAINT taxonbinmethod_stratumtype_id FOREIGN KEY (stratumtype_id)
422
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
423
      ON UPDATE CASCADE ON DELETE CASCADE
424
);
(8-8/12)