Project

General

Profile

1
-- Existing tables
2

    
3
CREATE TABLE role
4
(
5
  role_id int(11) NOT NULL AUTO_INCREMENT,
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 int(11) NOT NULL AUTO_INCREMENT,
14
  shortname character varying(250),
15
  fulltext__ text,
16
  referencetype character varying(250)
17
);
18

    
19
CREATE TABLE party
20
(
21
  party_id int(11) NOT NULL AUTO_INCREMENT,
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 int(11) NOT NULL AUTO_INCREMENT,
32
  plantname character varying(255) NOT NULL,
33
  reference_id int(11),
34
  dateentered timestamp NULL 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 int(11) NOT NULL AUTO_INCREMENT,
44
  plantname_id int(11) NOT NULL,
45
  reference_id int(11),
46
  plantcode character varying(23),
47
  plantdescription text,
48
  d_obscount int(11),
49
  d_currentaccepted int(1),
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 int(11) NOT NULL AUTO_INCREMENT,
63
  reference_id int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
77
  stratummethod_id int(11) 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 int(11) NOT NULL AUTO_INCREMENT,
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 int(11),
96
  d_obscount int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
108
  location_id int(11) NOT NULL,
109
  calculated int(1),
110
  namedplace_id int(11) 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 int(11) NOT NULL AUTO_INCREMENT,
124
  projectname character varying(150) NOT NULL,
125
  projectdescription text,
126
  startdate timestamp NULL,
127
  stopdate timestamp NULL,
128
  d_obscount int(11),
129
  d_lastlocationaddeddate timestamp NULL,
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 int(11) NOT NULL AUTO_INCREMENT,
140
  authorlocationcode character varying(30),
141
  reference_id int(11),
142
  parent_id int(11),
143
  reallatitude double precision,
144
  reallongitude double precision,
145
  locationaccuracy double precision,
146
  confidentialitystatus int(11) NOT NULL DEFAULT 0,
147
  confidentialityreason character varying(200),
148
  publiclatitude double precision,
149
  publiclongitude double precision,
150
  `... (truncated) ...` int(11),
151
  accessioncode character varying(255),
152
  sublocationxposition double precision,
153
  sublocationyposition double precision,
154
  namedplace_id int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
174
  previous_id int(11),
175
  location_id int(11),
176
  project_id int(11),
177
  authoreventcode character varying(30),
178
  `... (truncated) ...` int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
195
  locationevent_id int(11),
196
  authorplantname character varying(255),
197
  reference_id int(11),
198
  taxoninferencearea double precision,
199
  emb_taxonoccurrence int(11),
200
  `... (truncated) ...` int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
214
  taxonoccurrence_id int(11) NOT NULL,
215
  taxonbinmethod_id int(11),
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 int(11),
223
  covercode character varying(10),
224
  count int(11),
225
  accessioncode character varying(255),
226
  sourceaccessioncode character varying(100),
227
  CONSTRAINT aggregateoccurrence_pkey PRIMARY KEY (aggregateoccurrence_id ),
228
  CONSTRAINT aggregateoccurrence_taxonbinmethod_id FOREIGN KEY (taxonbinmethod_id)
229
      REFERENCES taxonbinmethod (taxonbinmethod_id) MATCH SIMPLE
230
      ON UPDATE CASCADE ON DELETE CASCADE,
231
  CONSTRAINT aggregateoccurrence_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
232
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
233
      ON UPDATE CASCADE ON DELETE CASCADE,
234
  CONSTRAINT aggregateoccurrence_keys_accessioncode UNIQUE (taxonoccurrence_id , sourceaccessioncode ),
235
  CONSTRAINT aggregateoccurrence_keys_method UNIQUE (taxonoccurrence_id , taxonbinmethod_id )
236
);
237

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

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

    
281
CREATE TABLE specimen -- A herbarium specimen. Contains Darwin Core specimen data.
282
(
283
  specimen_id int(11) NOT NULL AUTO_INCREMENT,
284
  reference_id int(11) NOT NULL,
285
  collectioncode_dwc character varying(255), -- The code for the collection that the specimen is from.
286
  catalognumber_dwc character varying(255),
287
  collectiondate timestamp NULL,
288
  museum_id int(11),
289
  sourceaccessioncode character varying(100),
290
  accessioncode character varying(255),
291
  taxonoccurrence_id int(11) NOT NULL,
292
  verbatimcollectorname character varying(255),
293
  collectionnumber character varying(255), -- The number of the specimen within the collection.
294
  CONSTRAINT specimen_pkey PRIMARY KEY (specimen_id ),
295
  CONSTRAINT specimen_museum_id FOREIGN KEY (museum_id)
296
      REFERENCES party (party_id) MATCH SIMPLE
297
      ON UPDATE CASCADE ON DELETE CASCADE,
298
  CONSTRAINT specimen_reference_id_fkey FOREIGN KEY (reference_id)
299
      REFERENCES reference (reference_id) MATCH SIMPLE
300
      ON UPDATE CASCADE ON DELETE CASCADE,
301
  CONSTRAINT specimen_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
302
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
303
      ON UPDATE CASCADE ON DELETE CASCADE,
304
  CONSTRAINT specimen_keys_accessioncode UNIQUE (reference_id , collectioncode_dwc , sourceaccessioncode ),
305
  CONSTRAINT specimen_keys_catalognumber UNIQUE (reference_id , collectioncode_dwc , catalognumber_dwc ),
306
  CONSTRAINT specimen_keys_code UNIQUE (reference_id , collectioncode_dwc , authorspecimencode )
307
);
308

    
309
CREATE TABLE voucher
310
(
311
  voucher_id int(11) NOT NULL AUTO_INCREMENT,
312
  taxonoccurrence_id int(11) NOT NULL,
313
  specimen_id int(11) NOT NULL,
314
  accessioncode character varying(255),
315
  CONSTRAINT voucher_pkey PRIMARY KEY (voucher_id ),
316
  CONSTRAINT voucher_specimen_id FOREIGN KEY (specimen_id)
317
      REFERENCES specimen (specimen_id) MATCH SIMPLE
318
      ON UPDATE CASCADE ON DELETE CASCADE,
319
  CONSTRAINT voucher_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
320
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
321
      ON UPDATE CASCADE ON DELETE CASCADE,
322
  CONSTRAINT voucher_keys UNIQUE (taxonoccurrence_id , specimen_id )
323
);
324

    
325
CREATE TABLE taxondetermination -- VegBank's taxoninterpretation table.
326
(
327
  taxondetermination_id int(11) NOT NULL AUTO_INCREMENT,
328
  taxonoccurrence_id int(11) NOT NULL,
329
  plantconcept_id int(11) NOT NULL,
330
  party_id int(11),
331
  role_id int(11) NOT NULL,
332
  determinationtype character varying(30),
333
  reference_id int(11),
334
  isoriginal int(1) NOT NULL DEFAULT false,
335
  iscurrent int(1) NOT NULL DEFAULT false,
336
  taxonfit character varying(50),
337
  taxonconfidence character varying(50),
338
  grouptype character varying(20),
339
  notes text,
340
  notespublic int(1),
341
  notesmgt int(1),
342
  revisions int(1),
343
  determinationdate timestamp NULL,
344
  emb_taxondetermination int(11),
345
  accessioncode character varying(255),
346
  CONSTRAINT taxondetermination_pkey PRIMARY KEY (taxondetermination_id ),
347
  CONSTRAINT taxondetermination_party_id FOREIGN KEY (party_id)
348
      REFERENCES party (party_id) MATCH SIMPLE
349
      ON UPDATE CASCADE ON DELETE CASCADE,
350
  CONSTRAINT taxondetermination_plantconcept_id FOREIGN KEY (plantconcept_id)
351
      REFERENCES plantconcept (plantconcept_id) MATCH SIMPLE
352
      ON UPDATE CASCADE ON DELETE CASCADE,
353
  CONSTRAINT taxondetermination_reference_id FOREIGN KEY (reference_id)
354
      REFERENCES reference (reference_id) MATCH SIMPLE
355
      ON UPDATE CASCADE ON DELETE CASCADE,
356
  CONSTRAINT taxondetermination_role_id FOREIGN KEY (role_id)
357
      REFERENCES role (role_id) MATCH SIMPLE
358
      ON UPDATE CASCADE ON DELETE CASCADE,
359
  CONSTRAINT taxondetermination_taxonoccurrence_id FOREIGN KEY (taxonoccurrence_id)
360
      REFERENCES taxonoccurrence (taxonoccurrence_id) MATCH SIMPLE
361
      ON UPDATE CASCADE ON DELETE CASCADE
362
);
363

    
364
CREATE TABLE stratum
365
(
366
  stratum_id int(11) NOT NULL AUTO_INCREMENT,
367
  locationevent_id int(11) NOT NULL,
368
  stratumtype_id int(11) NOT NULL,
369
  stratummethod_id int(11),
370
  stratumname character varying(30),
371
  stratumheight double precision,
372
  stratumbase double precision,
373
  stratumcover double precision,
374
  stratumdescription character varying(200),
375
  CONSTRAINT stratum_pkey PRIMARY KEY (stratum_id ),
376
  CONSTRAINT stratum_locationevent_id FOREIGN KEY (locationevent_id)
377
      REFERENCES locationevent (locationevent_id) MATCH SIMPLE
378
      ON UPDATE CASCADE ON DELETE CASCADE,
379
  CONSTRAINT stratum_stratumtype_id FOREIGN KEY (stratumtype_id)
380
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
381
      ON UPDATE CASCADE ON DELETE CASCADE
382
);
383

    
384
CREATE TABLE sizeclass -- A range of size measurements used to aggregate organisms.
385
(
386
  sizeclass_id int(11) NOT NULL AUTO_INCREMENT,
387
  mindiameter double precision,
388
  minheight double precision,
389
  maxdiameter double precision,
390
  maxheight double precision,
391
  accessioncode character varying(255),
392
  CONSTRAINT sizeclass_pkey PRIMARY KEY (sizeclass_id )
393
);
394

    
395
CREATE TABLE taxonbinmethod
396
(
397
  taxonbinmethod_id int(11) NOT NULL,
398
  label character varying(255),
399
  stratumtype_id int(11),
400
  sizeclass_id int(11),
401
  coverindex_id int(11),
402
  accessioncode character varying(255),
403
  CONSTRAINT taxonbinmethod_pkey PRIMARY KEY (taxonbinmethod_id ),
404
  CONSTRAINT taxonbinmethod_sizeclass_id FOREIGN KEY (sizeclass_id)
405
      REFERENCES sizeclass (sizeclass_id) MATCH SIMPLE
406
      ON UPDATE CASCADE ON DELETE CASCADE,
407
  CONSTRAINT taxonbinmethod_stratumtype_id FOREIGN KEY (stratumtype_id)
408
      REFERENCES stratumtype (stratumtype_id) MATCH SIMPLE
409
      ON UPDATE CASCADE ON DELETE CASCADE
410
);
(7-7/12)