Project

General

Profile

Task #934 ยป create_bien3_viewFullOccurrence.txt

DDL for step 1 of this task - Martha Narro, 06/04/2014 10:48 AM

 
1
-- -----------------------------------------------------------------------
2
-- Create the BIEN3 analytical table
3
--
4
-- Created by: Brad Boyle
5
-- Date created: 15 April 2014
6
-- -----------------------------------------------------------------------
7

    
8
-- -----------------------------------------------------------------------
9
-- Table: viewFullOccurrence
10
-- 
11
-- Uses: (1) Analyses requiring georeferenced occurrences (presence only) 
12
-- 		of species, (2) Analyses requiring standardized local abundance of 
13
-- 		species, (3) Analyses requiring additional information such as 
14
-- 		locality description, specimen description or observation date.
15
-- Scope: All georeferenced observations of taxa which are identified to
16
-- 		species level or lower, excluding morphospecies. Includes
17
--		specimen and plot observations, and trait observations, if 
18
-- 		georeferenced. A given species in a given
19
--		plot is recorded only once, with abundance summarized at the plot
20
-- 		level. Abundance applies only to plot observations, and it 
21
-- 		summarized in one of several columns as percent cover or counts 
22
-- 		of individuals at various minimum dbh cutoffs, whichever applies
23
-- 		to the plot in question. All observations in the database are 
24
--		included, and some may not be relevant or applicable to particular
25
-- 		analyses. Users are advised to filter records carefully using
26
--		columns such as isGeovalid, isCultivated, etc. (see Data Dictionary
27
-- 		for details). Trait measurements are not included; these should
28
-- 		be obtained from the separate analytical table "trait". 
29
-- Note: This table is modeled after table "observation" in the bien2 
30
-- 		bien2 analytical database "bien_web". However, I have 
31
-- 		preserved the name "viewFullOccurrence" because that is the 
32
-- 		name with which BIEN users are most familiar. Table 
33
-- 		bien_web.observation was a more metadata-rich version of 
34
-- 		viewFullOccurrence; it also corrected several issues present in 
35
-- 		the original bien2.viewFullOccurrence.
36
-- -----------------------------------------------------------------------
37

    
38
DROP TABLE IF EXISTS viewFullOccurrence;
39
CREATE TABLE viewFullOccurrence (
40
viewFullOccurrenceID INTEGER(11) UNSIGNED NOT NULL AUTO_INCREMENT,
41
occurrenceType VARCHAR(10) DEFAULT NULL,
42
datasetID INTEGER(11) UNSIGNED DEFAULT NULL,
43
datasetName VARCHAR(100) DEFAULT NULL,
44
proximateProviderID INTEGER(11) UNSIGNED DEFAULT NULL,
45
proximateProviderName VARCHAR(100) DEFAULT NULL,
46
primaryProviderID INTEGER(11) UNSIGNED DEFAULT NULL,
47
primaryProviderName VARCHAR(100) DEFAULT NULL,
48
specimenReplicateID INTEGER(11) UNSIGNED DEFAULT NULL,
49
specimenHerbariumAcronym VARCHAR(10) DEFAULT NULL, 
50
plotID INTEGER(11) UNSIGNED DEFAULT NULL,
51
plotCode VARCHAR(100) DEFAULT NULL,
52
taxonID INTEGER(11) UNSIGNED DEFAULT NULL,
53
taxonRank VARCHAR(50) DEFAULT NULL,
54
familyVerbatim VARCHAR(100) DEFAULT NULL,
55
taxonAuthorityVerbatim VARCHAR(255) DEFAULT NULL,
56
higherPlantGroup VARCHAR(25) DEFAULT NULL,
57
family VARCHAR(100) DEFAULT NULL,
58
genus VARCHAR(100) DEFAULT NULL,
59
species VARCHAR(150) DEFAULT NULL,
60
taxon VARCHAR(200) DEFAULT NULL,
61
taxonAuthor VARCHAR(255) DEFAULT NULL,
62
taxonMorphospecies VARCHAR(255) DEFAULT NULL,
63
tnrsTaxonomicStatus VARCHAR(2) DEFAULT NULL,
64
country VARCHAR(50) DEFAULT NULL,
65
stateProvince VARCHAR(100) DEFAULT NULL,
66
countyParish VARCHAR(100) DEFAULT NULL,
67
countryError double DEFAULT NULL,
68
stateProvinceError double DEFAULT NULL,
69
countyParishError double DEFAULT NULL,
70
latitudeVerbatim VARCHAR(150) DEFAULT NULL,
71
longitudeVerbatim VARCHAR(150) DEFAULT NULL,
72
latitude DECIMAL(10,5) DEFAULT NULL,
73
longitude DECIMAL(10,5) DEFAULT NULL,
74
elevation_m decimal(6,1) DEFAULT NULL,
75
isGeovalid INTEGER(1) DEFAULT NULL,
76
isNewWorld INTEGER(1) DEFAULT NULL,
77
isIntroduced INTEGER(1) default 0,
78
isCultivated INTEGER(1) default 0,
79
specimenCollector VARCHAR(150) DEFAULT NULL,
80
observationDate DATE DEFAULT NULL,
81
identifiedBy VARCHAR(150) DEFAULT NULL,
82
identifiedDate DATE DEFAULT NULL, 
83
localityDescription VARCHAR(500) DEFAULT NULL,
84
specimenDescription VARCHAR(500) DEFAULT NULL,
85
plotCode VARCHAR(100) DEFAULT NULL,
86
plotMethod VARCHAR(100) DEFAULT NULL,
87
plotAreaHa double DEFAULT NULL,
88
plotMinDbh decimal(5,1) DEFAULT NULL,
89
abund INTEGER(11) DEFAULT NULL,
90
abund1 INTEGER(11) DEFAULT NULL,
91
`abund2.5` INTEGER(11) DEFAULT NULL,
92
abund10 INTEGER(11) DEFAULT NULL,
93
percentCover DECIMAL(10,5) DEFAULT NULL
94
) engine=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_general_ci;
95

    
96
-- Indexes on table viewFullOccurrence
97
ALTER TABLE viewFullOccurrence
98
ADD PRIMARY KEY (viewFullOccurrenceID),
99
ADD INDEX (occurrenceType),
100
ADD INDEX (datasetID),
101
ADD INDEX (datasetName),
102
ADD INDEX (proximateProviderID),
103
ADD INDEX (proximateProviderName),
104
ADD INDEX (primaryProviderID),
105
ADD INDEX (primaryProviderName),
106
ADD INDEX (specimenReplicateID),
107
ADD INDEX (specimenHerbariumAcronym),
108
ADD INDEX (plotID),
109
ADD INDEX (plotCode),
110
ADD INDEX (taxonID),
111
ADD INDEX (taxonRank),
112
ADD INDEX (familyVerbatim),
113
ADD INDEX (taxonAuthorityVerbatim),
114
ADD INDEX (higherPlantGroup),
115
ADD INDEX (family),
116
ADD INDEX (genus),
117
ADD INDEX (species),
118
ADD INDEX (taxon),
119
ADD INDEX (taxonAuthor),
120
ADD INDEX (taxonMorphospecies),
121
ADD INDEX (tnrsTaxonomicStatus),
122
ADD INDEX (country),
123
ADD INDEX (stateProvince),
124
ADD INDEX (countyParish),
125
ADD INDEX (isGeovalid),
126
ADD INDEX (isNewWorld),
127
ADD INDEX (isIntroduced),
128
ADD INDEX (isCultivated),
129
ADD INDEX (specimenCollector),
130
ADD INDEX (identifiedBy),
131
ADD INDEX (plotCode),
132
ADD INDEX (plotMethod),
133
ADD INDEX (plotAreaHa),
134
ADD INDEX (plotMinDbh)
135
;
136

    
    (1-1/1)