Project

General

Profile

1
-- Existing tables
2

    
3
CREATE TABLE aux_role
4
(
5
  role_id serial NOT NULL,
6
  rolecode character varying(30) NOT NULL,
7
  roledescription character varying(200),
8
  CONSTRAINT aux_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 NOT NULL,
46
  plantname character varying(200),
47
  plantcode character varying(23),
48
  plantdescription text,
49
  d_obscount integer,
50
  d_currentaccepted boolean,
51
  accessioncode character varying(255),
52
  CONSTRAINT plantconcept_pkey PRIMARY KEY (plantconcept_id ),
53
  CONSTRAINT plantconcept_plantname_id FOREIGN KEY (plantname_id)
54
      REFERENCES plantname (plantname_id) MATCH SIMPLE
55
      ON UPDATE CASCADE ON DELETE CASCADE,
56
  CONSTRAINT plantconcept_reference_id FOREIGN KEY (reference_id)
57
      REFERENCES reference (reference_id) MATCH SIMPLE
58
      ON UPDATE CASCADE ON DELETE CASCADE
59
);
60

    
61
CREATE TABLE namedplace
62
(
63
  namedplace_id serial NOT NULL,
64
  placesystem character varying(50),
65
  placename character varying(100) NOT NULL,
66
  placedescription text,
67
  placecode character varying(15),
68
  owner character varying(100),
69
  reference_id integer,
70
  d_obscount integer,
71
  accessioncode character varying(255),
72
  CONSTRAINT namedplace_pkey PRIMARY KEY (namedplace_id ),
73
  CONSTRAINT namedplace_reference_id FOREIGN KEY (reference_id)
74
      REFERENCES reference (reference_id) MATCH SIMPLE
75
      ON UPDATE CASCADE ON DELETE CASCADE,
76
  CONSTRAINT namedplace_keys UNIQUE (placesystem , placename )
77
);
78

    
79
CREATE TABLE locationplace
80
(
81
  locationplace_id serial NOT NULL,
82
  location_id integer NOT NULL,
83
  calculated boolean,
84
  namedplace_id integer NOT NULL,
85
  CONSTRAINT locationplace_pkey PRIMARY KEY (locationplace_id ),
86
  CONSTRAINT locationplace_location_id FOREIGN KEY (location_id)
87
      REFERENCES location (location_id) MATCH SIMPLE
88
      ON UPDATE CASCADE ON DELETE CASCADE,
89
  CONSTRAINT locationplace_namedplace_id FOREIGN KEY (namedplace_id)
90
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
91
      ON UPDATE CASCADE ON DELETE CASCADE,
92
  CONSTRAINT locationplace_keys UNIQUE (location_id , namedplace_id )
93
);
94

    
95
CREATE TABLE project
96
(
97
  project_id serial NOT NULL,
98
  projectname character varying(150) NOT NULL,
99
  projectdescription text,
100
  startdate timestamp with time zone,
101
  stopdate timestamp with time zone,
102
  d_obscount integer,
103
  d_lastlocationaddeddate timestamp with time zone,
104
  accessioncode character varying(255),
105
  CONSTRAINT project_pkey PRIMARY KEY (project_id ),
106
  CONSTRAINT project_keys UNIQUE (projectname , startdate , stopdate )
107
);
108

    
109
-- New tables
110

    
111
CREATE TABLE location
112
(
113
  location_id serial NOT NULL,
114
  authorlocationcode character varying(30),
115
  reference_id integer,
116
  parent_id integer,
117
  reallatitude double precision,
118
  reallongitude double precision,
119
  locationaccuracy double precision,
120
  confidentialitystatus integer NOT NULL DEFAULT 0,
121
  confidentialityreason character varying(200),
122
  publiclatitude double precision,
123
  publiclongitude double precision,
124
  "... (truncated) ..." integer,
125
  accessioncode character varying(255),
126
  sublocationxposition double precision,
127
  sublocationyposition double precision,
128
  namedplace_id integer,
129
  CONSTRAINT location_pkey PRIMARY KEY (location_id ),
130
  CONSTRAINT location_namedplace_id FOREIGN KEY (namedplace_id)
131
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
132
      ON UPDATE CASCADE ON DELETE CASCADE,
133
  CONSTRAINT location_parent_id FOREIGN KEY (parent_id)
134
      REFERENCES location (location_id) MATCH SIMPLE
135
      ON UPDATE CASCADE ON DELETE CASCADE,
136
  CONSTRAINT location_reference_id FOREIGN KEY (reference_id)
137
      REFERENCES reference (reference_id) MATCH SIMPLE
138
      ON UPDATE CASCADE ON DELETE CASCADE,
139
  CONSTRAINT location_keys_code UNIQUE (reference_id , authorlocationcode ),
140
  CONSTRAINT location_keys_coords UNIQUE (reference_id , reallatitude , reallongitude ),
141
  CONSTRAINT location_keys_subplot_code UNIQUE (parent_id , authorlocationcode ),
142
  CONSTRAINT location_keys_subplot_coords UNIQUE (parent_id , sublocationxposition , sublocationyposition )
143
);
144

    
145
CREATE TABLE locationevent -- VegBank's observation table.
146
(
147
  locationevent_id serial NOT NULL,
148
  previous_id integer,
149
  location_id integer NOT NULL,
150
  project_id integer,
151
  authoreventcode character varying(30),
152
  "... (truncated) ..." integer,
153
  accessioncode character varying(255),
154
  sourceaccessioncode character varying(100),
155
  CONSTRAINT locationevent_pkey PRIMARY KEY (locationevent_id ),
156
  CONSTRAINT locationevent_location_id FOREIGN KEY (location_id)
157
      REFERENCES location (location_id) MATCH SIMPLE
158
      ON UPDATE CASCADE ON DELETE CASCADE,
159
  CONSTRAINT locationevent_project_id FOREIGN KEY (project_id)
160
      REFERENCES project (project_id) MATCH SIMPLE
161
      ON UPDATE CASCADE ON DELETE CASCADE,
162
  CONSTRAINT locationevent_keys_accessioncode UNIQUE (location_id , project_id , sourceaccessioncode ),
163
  CONSTRAINT locationevent_keys_code UNIQUE (location_id , project_id , authoreventcode )
164
);
165

    
166
CREATE TABLE taxonoccurrence -- VegBank's taxonobservation table.
167
(
168
  taxonoccurrence_id serial NOT NULL,
169
  locationevent_id integer NOT NULL,
170
  authorplantname character varying(255),
171
  reference_id integer,
172
  taxoninferencearea double precision,
173
  emb_taxonoccurrence integer,
174
  "... (truncated) ..." integer,
175
  accessioncode character varying(255),
176
  CONSTRAINT taxonoccurrence_pkey PRIMARY KEY (taxonoccurrence_id ),
177
  CONSTRAINT taxonoccurrence_locationevent_id FOREIGN KEY (locationevent_id)
178
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
179
      ON UPDATE CASCADE ON DELETE CASCADE,
180
  CONSTRAINT taxonoccurrence_reference_id FOREIGN KEY (reference_id)
181
      REFERENCES reference (reference_id) MATCH SIMPLE
182
      ON UPDATE CASCADE ON DELETE CASCADE
183
);
184

    
185
CREATE TABLE aggregateoccurrence -- VegBank's taxonimportance table.
186
(
187
  aggregateoccurrence_id serial NOT NULL,
188
  taxonoccurrence_id integer NOT NULL,
189
  taxonbinmethod_id integer,
190
  cover double precision,
191
  basalarea double precision,
192
  biomass double precision,
193
  inferencearea double precision,
194
  stratumbase double precision,
195
  stratumheight double precision,
196
  emb_aggregateoccurrence integer,
197
  covercode character varying(10),
198
  count integer NOT NULL,
199
  accessioncode character varying(255),
200
  sourceaccessioncode character varying(100),
201
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
202
  CONSTRAINT aggregateoccurrence_taxonbinmethod_id FOREIGN KEY (taxonbinmethod_id)
203
      REFERENCES taxonbinmethod (taxonbinmethod_id) MATCH SIMPLE
204
      ON UPDATE CASCADE ON DELETE CASCADE,
205
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
206
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
207
      ON UPDATE CASCADE ON DELETE CASCADE,
208
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode ),
209
  CONSTRAINT aggregateoccurrence_keys_method UNIQUE (taxonoccurrence_id , taxonbinmethod_id )
210
);
211

    
212
CREATE TABLE individualplant -- VegBank's stemcount table.
213
(
214
  individualplant_id serial NOT NULL,
215
  aggregateoccurrence_id integer NOT NULL,
216
  overallheight double precision,
217
  overallheightaccuracy double precision,
218
  emb_individualplant integer,
219
  authorplantcode character varying(20),
220
  accessioncode character varying(255),
221
  stemcount integer,
222
  sourceaccessioncode character varying(100),
223
  CONSTRAINT individualplant_pkey PRIMARY KEY (individualplant_id ),
224
  CONSTRAINT individualplant_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id)
225
      REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE
226
      ON UPDATE CASCADE ON DELETE CASCADE,
227
  CONSTRAINT individualplant_keys_accessioncode UNIQUE (aggregateoccurrence_id , sourceaccessioncode ),
228
  CONSTRAINT individualplant_keys_code UNIQUE (aggregateoccurrence_id , authorplantcode )
229
);
230

    
231
CREATE TABLE stem -- VegBank's stemlocation table.
232
(
233
  stem_id serial NOT NULL,
234
  individualplant_id integer NOT NULL,
235
  authorstemcode character varying(20),
236
  xposition double precision,
237
  yposition double precision,
238
  health character varying(50),
239
  emb_stem integer,
240
  diameter double precision,
241
  height double precision,
242
  heightaccuracy double precision,
243
  age double precision,
244
  accessioncode character varying(255),
245
  diameteraccuracy double precision,
246
  sourceaccessioncode character varying(100),
247
  CONSTRAINT stem_pkey PRIMARY KEY (stem_id ),
248
  CONSTRAINT stem_individualplant_id FOREIGN KEY (individualplant_id)
249
      REFERENCES individualplant (individualplant_id) MATCH SIMPLE
250
      ON UPDATE CASCADE ON DELETE CASCADE,
251
  CONSTRAINT stem_keys_accessioncode UNIQUE (individualplant_id , sourceaccessioncode ),
252
  CONSTRAINT stem_keys_code UNIQUE (individualplant_id , authorstemcode )
253
);
254

    
255
CREATE TABLE specimen -- A herbarium specimen. Contains Darwin Core specimen data.
256
(
257
  specimen_id serial NOT NULL,
258
  reference_id integer NOT NULL,
259
  collectioncode_dwc character varying(255),
260
  catalognumber_dwc character varying(255),
261
  collectiondate timestamp with time zone,
262
  collector_id integer,
263
  museum_id integer,
264
  sourceaccessioncode character varying(100),
265
  accessioncode character varying(255),
266
  taxonoccurrence_id integer NOT NULL,
267
  collectornumber_dwc character varying(255),
268
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id ),
269
  CONSTRAINT specimen_collector_id FOREIGN KEY (collector_id)
270
      REFERENCES party (party_id) MATCH SIMPLE
271
      ON UPDATE CASCADE ON DELETE CASCADE,
272
  CONSTRAINT specimen_museum_id FOREIGN KEY (museum_id)
273
      REFERENCES party (party_id) MATCH SIMPLE
274
      ON UPDATE CASCADE ON DELETE CASCADE,
275
  CONSTRAINT specimen_reference_id_fkey FOREIGN KEY (reference_id)
276
      REFERENCES reference (reference_id) MATCH SIMPLE
277
      ON UPDATE CASCADE ON DELETE CASCADE,
278
  CONSTRAINT specimen_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
279
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
280
      ON UPDATE CASCADE ON DELETE CASCADE,
281
  CONSTRAINT specimen_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
282
  CONSTRAINT specimen_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc )
283
);
284

    
285
CREATE TABLE voucher
286
(
287
  voucher_id serial NOT NULL,
288
  taxonoccurrence_id integer NOT NULL,
289
  specimen_id integer NOT NULL,
290
  accessioncode character varying(255),
291
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
292
  CONSTRAINT voucher_specimen_id FOREIGN KEY (specimen_id)
293
      REFERENCES specimen (specimen_id) MATCH SIMPLE
294
      ON UPDATE CASCADE ON DELETE CASCADE,
295
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
296
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
297
      ON UPDATE CASCADE ON DELETE CASCADE,
298
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimen_id )
299
);
300

    
301
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
302
(
303
  taxondetermination_id serial NOT NULL,
304
  taxonoccurrence_id integer NOT NULL,
305
  plantconcept_id integer NOT NULL,
306
  party_id integer,
307
  role_id integer NOT NULL,
308
  determinationtype character varying(30),
309
  reference_id integer,
310
  originaldetermination boolean NOT NULL DEFAULT false,
311
  currentdetermination boolean NOT NULL DEFAULT false,
312
  taxonfit character varying(50),
313
  taxonconfidence character varying(50),
314
  grouptype character varying(20),
315
  notes text,
316
  notespublic boolean,
317
  notesmgt boolean,
318
  revisions boolean,
319
  determinationdate timestamp with time zone NOT NULL,
320
  emb_taxondetermination integer,
321
  accessioncode character varying(255),
322
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
323
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
324
      REFERENCES party (party_id) MATCH SIMPLE
325
      ON UPDATE CASCADE ON DELETE CASCADE,
326
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
327
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
328
      ON UPDATE CASCADE ON DELETE CASCADE,
329
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
330
      REFERENCES reference (reference_id) MATCH SIMPLE
331
      ON UPDATE CASCADE ON DELETE CASCADE,
332
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
333
      REFERENCES aux_role (role_id) MATCH SIMPLE
334
      ON UPDATE CASCADE ON DELETE CASCADE,
335
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
336
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
337
      ON UPDATE CASCADE ON DELETE CASCADE
338
);
339

    
340
CREATE TABLE stratum
341
(
342
  stratum_id serial NOT NULL,
343
  locationevent_id integer NOT NULL,
344
  stratumtype_id integer NOT NULL,
345
  stratummethod_id integer,
346
  stratumname character varying(30),
347
  stratumheight double precision,
348
  stratumbase double precision,
349
  stratumcover double precision,
350
  stratumdescription character varying(200),
351
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
352
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
353
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
354
      ON UPDATE CASCADE ON DELETE CASCADE
355
);
356

    
357
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
358
(
359
  sizeclass_id serial NOT NULL,
360
  mindiameter double precision,
361
  minheight double precision,
362
  maxdiameter double precision,
363
  maxheight double precision,
364
  accessioncode character varying(255),
365
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
366
);
367

    
368
CREATE TABLE taxonbinmethod -- Defines a set of aggregate measurements. Used by aggregateoccurrence to define how measurements were aggregated.
369
(
370
  taxonbinmethod_id integer NOT NULL,
371
  label character varying(255) NOT NULL DEFAULT ''::character varying,
372
  stratum_id integer,
373
  sizeclass_id integer,
374
  coverindex_id integer,
375
  accessioncode character varying(255),
376
  CONSTRAINT taxonbinmethod_pkey PRIMARY KEY (taxonbinmethod_id ),
377
  CONSTRAINT taxonbinmethod_sizeclass_id FOREIGN KEY (sizeclass_id)
378
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
379
      ON UPDATE CASCADE ON DELETE CASCADE,
380
  CONSTRAINT taxonbinmethod_keys UNIQUE (label , stratum_id , sizeclass_id , coverindex_id )
381
);
(8-8/12)