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) NOT NULL DEFAULT ''::character varying,
115
  reference_id integer,
116
  parent_id integer,
117
  reallatitude double precision NOT NULL DEFAULT 'NaN'::double precision,
118
  reallongitude double precision NOT NULL DEFAULT 'NaN'::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 UNIQUE (reference_id , authorlocationcode , reallatitude , reallongitude ),
140
  CONSTRAINT location_keys_subplot UNIQUE (parent_id , authorlocationcode , reallatitude , reallongitude )
141
);
142

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

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

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

    
206
CREATE TABLE individualplant -- VegBank's stemcount table.
207
(
208
  individualplant_id serial NOT NULL,
209
  aggregateoccurrence_id integer NOT NULL,
210
  overallheight double precision,
211
  overallheightaccuracy double precision,
212
  emb_individualplant integer,
213
  authorplantcode character varying(20),
214
  accessioncode character varying(255),
215
  stemcount integer,
216
  CONSTRAINT individualplant_pkey PRIMARY KEY (individualplant_id ),
217
  CONSTRAINT individualplant_aggregateoccurrence_id FOREIGN KEY (aggregateoccurrence_id)
218
      REFERENCES aggregateoccurrence (aggregateoccurrence_id) MATCH SIMPLE
219
      ON UPDATE CASCADE ON DELETE CASCADE,
220
  CONSTRAINT individualplant_keys UNIQUE (aggregateoccurrence_id , authorplantcode )
221
);
222

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

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

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

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

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

    
346
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
347
(
348
  sizeclass_id serial NOT NULL,
349
  mindiameter double precision,
350
  minheight double precision,
351
  maxdiameter double precision,
352
  maxheight double precision,
353
  accessioncode character varying(255),
354
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
355
);
356

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