Project

General

Profile

1
-- Existing tables
2

    
3
CREATE TABLE aux_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 aux_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 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) NOT NULL,
46
  plantname character varying(200),
47
  plantcode character varying(23),
48
  plantdescription text,
49
  d_obscount int(11),
50
  d_currentaccepted int(1),
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 int(11) NOT NULL AUTO_INCREMENT,
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 int(11),
70
  d_obscount int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
82
  location_id int(11) NOT NULL,
83
  calculated int(1),
84
  namedplace_id int(11) 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 int(11) NOT NULL AUTO_INCREMENT,
98
  projectname character varying(150) NOT NULL,
99
  projectdescription text,
100
  startdate timestamp NULL,
101
  stopdate timestamp NULL,
102
  d_obscount int(11),
103
  d_lastlocationaddeddate timestamp NULL,
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 int(11) NOT NULL AUTO_INCREMENT,
114
  authorlocationcode character varying(30),
115
  reference_id int(11),
116
  parent_id int(11),
117
  reallatitude double precision,
118
  reallongitude double precision,
119
  locationaccuracy double precision,
120
  confidentialitystatus int(11) NOT NULL DEFAULT 0,
121
  confidentialityreason character varying(200),
122
  publiclatitude double precision,
123
  publiclongitude double precision,
124
  `... (truncated) ...` int(11),
125
  accessioncode character varying(255),
126
  sublocationxposition double precision,
127
  sublocationyposition double precision,
128
  namedplace_id int(11),
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 int(11) NOT NULL AUTO_INCREMENT,
148
  previous_id int(11),
149
  location_id int(11) NOT NULL,
150
  project_id int(11),
151
  authoreventcode character varying(30),
152
  `... (truncated) ...` int(11),
153
  accessioncode character varying(255),
154
  CONSTRAINT locationevent_pkey PRIMARY KEY (locationevent_id ),
155
  CONSTRAINT locationevent_location_id FOREIGN KEY (location_id)
156
      REFERENCES location (location_id) MATCH SIMPLE
157
      ON UPDATE CASCADE ON DELETE CASCADE,
158
  CONSTRAINT locationevent_project_id FOREIGN KEY (project_id)
159
      REFERENCES project (project_id) MATCH SIMPLE
160
      ON UPDATE CASCADE ON DELETE CASCADE,
161
  CONSTRAINT locationevent_keys UNIQUE (location_id , project_id , authoreventcode )
162
);
163

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

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

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

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

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

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

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

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

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

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