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 place
80
(
81
  locationplace_id serial NOT NULL,
82
  location_id integer NOT NULL,
83
  calculated boolean,
84
  namedplace_id integer NOT NULL,
85
  CONSTRAINT place_pkey PRIMARY KEY (locationplace_id ),
86
  CONSTRAINT place_location_id FOREIGN KEY (location_id)
87
      REFERENCES location (location_id) MATCH SIMPLE
88
      ON UPDATE CASCADE ON DELETE CASCADE,
89
  CONSTRAINT place_namedplace_id FOREIGN KEY (namedplace_id)
90
      REFERENCES namedplace (namedplace_id) MATCH SIMPLE
91
      ON UPDATE CASCADE ON DELETE CASCADE,
92
  CONSTRAINT place_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
  sourceid 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,
121
  confidentialityreason character varying(200),
122
  latitude double precision,
123
  longitude double precision,
124
  -- ...
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 UNIQUE (reference_id , parent_id , sourceid )
140
);
141

    
142
CREATE TABLE locationevent -- VegBank's observation table.
143
(
144
  locationevent_id serial NOT NULL,
145
  previous_id integer,
146
  location_id integer NOT NULL,
147
  project_id integer,
148
  sourceid character varying(30),
149
  -- ...
150
  accessioncode character varying(255),
151
  CONSTRAINT locationevent_pkey PRIMARY KEY (locationevent_id ),
152
  CONSTRAINT locationevent_location_id FOREIGN KEY (location_id)
153
      REFERENCES location (location_id) MATCH SIMPLE
154
      ON UPDATE CASCADE ON DELETE CASCADE,
155
  CONSTRAINT locationevent_project_id FOREIGN KEY (project_id)
156
      REFERENCES project (project_id) MATCH SIMPLE
157
      ON UPDATE CASCADE ON DELETE CASCADE,
158
  CONSTRAINT locationevent_keys UNIQUE (location_id , project_id , sourceid )
159
);
160

    
161
CREATE TABLE taxonoccurrence -- VegBank's taxonobservation table.
162
(
163
  taxonoccurrence_id serial NOT NULL,
164
  locationevent_id integer NOT NULL,
165
  authorplantname character varying(255),
166
  reference_id integer,
167
  taxoninferencearea double precision,
168
  emb_taxonoccurrence integer,
169
  -- ...
170
  accessioncode character varying(255),
171
  currentdetermination_id integer,
172
  originaldetermination_id integer,
173
  CONSTRAINT taxonoccurrence_pkey PRIMARY KEY (taxonoccurrence_id ),
174
  CONSTRAINT taxonoccurrence_currentdetermination_id FOREIGN KEY (currentdetermination_id)
175
      REFERENCES taxondetermination (taxondetermination_id) MATCH SIMPLE
176
      ON UPDATE CASCADE ON DELETE CASCADE,
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_originaldetermination_id FOREIGN KEY (originaldetermination_id)
181
      REFERENCES taxondetermination (taxondetermination_id) MATCH SIMPLE
182
      ON UPDATE CASCADE ON DELETE CASCADE,
183
  CONSTRAINT taxonoccurrence_reference_id FOREIGN KEY (reference_id)
184
      REFERENCES reference (reference_id) MATCH SIMPLE
185
      ON UPDATE CASCADE ON DELETE CASCADE
186
);
187

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

    
213
CREATE TABLE individualplant -- VegBank's stemcount table.
214
(
215
  individualplant_id serial NOT NULL,
216
  aggregateoccurrence_id integer NOT NULL,
217
  height double precision,
218
  heightaccuracy double precision,
219
  emb_individualplant integer,
220
  sourceid character varying(20),
221
  accessioncode character varying(255),
222
  stemcount integer,
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 UNIQUE (aggregateoccurrence_id , sourceid )
228
);
229

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

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

    
279
CREATE TABLE voucher
280
(
281
  voucher_id serial NOT NULL,
282
  taxonoccurrence_id integer NOT NULL,
283
  specimen_id integer NOT NULL,
284
  accessioncode character varying(255),
285
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
286
  CONSTRAINT voucher_specimen_id FOREIGN KEY (specimen_id)
287
      REFERENCES specimen (specimen_id) MATCH SIMPLE
288
      ON UPDATE CASCADE ON DELETE CASCADE,
289
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
290
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
291
      ON UPDATE CASCADE ON DELETE CASCADE,
292
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimen_id )
293
);
294

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

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

    
351
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
352
(
353
  sizeclass_id serial NOT NULL,
354
  mindiameter double precision,
355
  diameteraccuracy double precision,
356
  minheight double precision,
357
  heightaccuracy double precision,
358
  maxdiameter double precision,
359
  maxheight double precision,
360
  accessioncode character varying(255),
361
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
362
);
363

    
364
CREATE TABLE taxonbin -- Defines a set of aggregate measurements. Used by aggregateoccurrence to define how measurements were aggregated.
365
(
366
  taxonbin_id integer NOT NULL,
367
  label character varying(255) NOT NULL,
368
  stratum_id integer,
369
  sizeclass_id integer,
370
  coverindex_id integer,
371
  accessioncode character varying(255),
372
  CONSTRAINT taxonbin_pkey PRIMARY KEY (taxonbin_id ),
373
  CONSTRAINT taxonbin_sizeclass_id FOREIGN KEY (sizeclass_id)
374
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
375
      ON UPDATE CASCADE ON DELETE CASCADE
376
);
(8-8/12)