1
|
Test queries against SALVIAS native database
|
2
|
- all queries against MySQL db `salvias_plots` on nimoy
|
3
|
|
4
|
1. Count projects
|
5
|
|
6
|
SELECT COUNT(*) FROM projects;
|
7
|
+----------+
|
8
|
| COUNT(*) |
|
9
|
+----------+
|
10
|
| 23 |
|
11
|
+----------+
|
12
|
1 row in set (0.00 sec)
|
13
|
|
14
|
2. Count plots
|
15
|
|
16
|
SELECT COUNT(*) FROM plotMetadata;
|
17
|
mysql> SELECT COUNT(*) FROM plotMetadata;
|
18
|
+----------+
|
19
|
| COUNT(*) |
|
20
|
+----------+
|
21
|
| 13661 |
|
22
|
+----------+
|
23
|
1 row in set (0.00 sec)
|
24
|
|
25
|
3. Count plots per project
|
26
|
|
27
|
SELECT pr.project_id, project_name, COUNT(PlotID)
|
28
|
FROM projects pr JOIN plotMetadata p
|
29
|
ON pr.project_id=p.project_id
|
30
|
GROUP BY pr.project_id, project_name;
|
31
|
-> GROUP BY pr.project_id, project_name;
|
32
|
+------------+------------------------------------------------+---------------+
|
33
|
| project_id | project_name | COUNT(PlotID) |
|
34
|
+------------+------------------------------------------------+---------------+
|
35
|
| 1 | Gentry Transect Dataset | 228 |
|
36
|
| 2 | Boyle Transects | 37 |
|
37
|
| 3 | OTS Transects | 20 |
|
38
|
| 5 | RAINFOR - 0.1 ha Madre de Dios, Peru | 102 |
|
39
|
| 6 | Noel Kempff Forest Plots | 29 |
|
40
|
| 7 | Noel Kempff Savanna Plots | 9 |
|
41
|
| 8 | Inventarios de Bosques en Ecuador | 1 |
|
42
|
| 9 | Inventarios de Bosques de la Costa del Ecuador | 1 |
|
43
|
| 10 | Enquist Lab Transect Dataset | 22 |
|
44
|
| 11 | INW Vegetation Plots | 12962 |
|
45
|
| 12 | Cam Webb Borneo Plots | 28 |
|
46
|
| 13 | Pilon Lajas Treeplots Bolivia | 2 |
|
47
|
| 14 | Madidi Transects | 99 |
|
48
|
| 16 | nsf_example | 2 |
|
49
|
| 17 | Madidi Permanent Plots | 6 |
|
50
|
| 18 | SERBO Selva Seca Oaxaca | 3 |
|
51
|
| 19 | DeWalt Bolivia forest plots | 4 |
|
52
|
| 21 | La Selva Secondary Forest Plots | 3 |
|
53
|
| 22 | ACA Amazon Forest Inventories | 1 |
|
54
|
| 23 | Madidi Savana Line Transects | 70 |
|
55
|
| 24 | Bonifacino Forest Transects | 4 |
|
56
|
| 25 | RAINFOR - 1 ha Peru | 28 |
|
57
|
+------------+------------------------------------------------+---------------+
|
58
|
22 rows in set (0.12 sec)
|
59
|
|
60
|
4. Count of individuals per plot for single project
|
61
|
|
62
|
First, look up examples of methodologies used in different projects:
|
63
|
|
64
|
SELECT DISTINCT pr.project_id, project_name, PlotMethod, m.MethodCode, m.Description
|
65
|
FROM projects pr JOIN plotMetadata p JOIN lookup_MethodCode m
|
66
|
ON pr.project_id=p.project_id AND p.MethodCode=m.MethodCode
|
67
|
LIMIT 10;
|
68
|
+------------+------------------------------------------------+--------------------------------------------+------------+--------------------------+
|
69
|
| project_id | project_name | PlotMethod | MethodCode | Description |
|
70
|
+------------+------------------------------------------------+--------------------------------------------+------------+--------------------------+
|
71
|
| 1 | Gentry Transect Dataset | 0.1 ha transect, stems >= 2.5 cm dbh | 8 | species (stems) |
|
72
|
| 2 | Boyle Transects | 0.1 ha transect, stems >= 2.5 cm dbh | 3 | individuals |
|
73
|
| 3 | OTS Transects | 0.1 ha transect, stems >= 2.5 cm dbh | 3 | individuals |
|
74
|
| 5 | RAINFOR - 0.1 ha Madre de Dios, Peru | 0.1 ha transect, stems >= 2.5 cm dbh | 3 | individuals |
|
75
|
| 6 | Noel Kempff Forest Plots | 1 ha, stems >= 10 cm dbh | 3 | individuals |
|
76
|
| 7 | Noel Kempff Savanna Plots | Point-intercept | 7 | species (line-intercept) |
|
77
|
| 8 | Inventarios de Bosques en Ecuador | 1 ha, stems >= 10 cm dbh | 3 | individuals |
|
78
|
| 9 | Inventarios de Bosques de la Costa del Ecuador | 1 ha, stems >= 10 cm dbh | 3 | individuals |
|
79
|
| 10 | Enquist Lab Transect Dataset | 0.1 ha transect, stems >= 2.5 cm dbh | 3 | individuals |
|
80
|
| 11 | INW Vegetation Plots | 20 m x 20 cover plots, all vascular plants | 1 | species (percent cover) |
|
81
|
+------------+------------------------------------------------+--------------------------------------------+------------+--------------------------+
|
82
|
10 rows in set (0.00 sec)
|
83
|
|
84
|
project 2 will do (Boyle Transects). Are all individual observations.
|
85
|
|
86
|
Now, let's count using two different methods:
|
87
|
|
88
|
(a) method one: count observations (valid for lookup_MethodCode='individuals' only)
|
89
|
|
90
|
SELECT p.PlotID, p.SiteCode, COUNT(*)
|
91
|
FROM projects pr JOIN plotMetadata p JOIN plotObservations o
|
92
|
ON pr.project_id=p.project_id AND p.PlotID=o.PlotID
|
93
|
WHERE p.project_id=2
|
94
|
GROUP BY p.PlotID, p.SiteCode;
|
95
|
+--------+----------+----------+
|
96
|
| PlotID | SiteCode | COUNT(*) |
|
97
|
+--------+----------+----------+
|
98
|
| 290 | c1000-1 | 321 |
|
99
|
| 291 | c1250-1 | 228 |
|
100
|
| 292 | c1750-1 | 270 |
|
101
|
| 293 | c1750-2 | 195 |
|
102
|
| 294 | c1750-3 | 274 |
|
103
|
| 295 | c2000-1 | 362 |
|
104
|
| 296 | c2000-2 | 352 |
|
105
|
| 297 | c2250-1 | 439 |
|
106
|
| 298 | c2750-1 | 189 |
|
107
|
| 299 | c2750-2 | 251 |
|
108
|
| 300 | c2750-3 | 248 |
|
109
|
| 301 | c500-1 | 273 |
|
110
|
| 302 | c750-1 | 298 |
|
111
|
| 303 | c750-2 | 303 |
|
112
|
| 304 | c750-3 | 295 |
|
113
|
| 305 | e1250-1 | 444 |
|
114
|
| 306 | e1750-1 | 313 |
|
115
|
| 307 | e1750-2 | 435 |
|
116
|
| 308 | e1750-3 | 402 |
|
117
|
| 309 | e2250-1 | 399 |
|
118
|
| 310 | e2250-2 | 316 |
|
119
|
| 311 | e2750-1 | 310 |
|
120
|
| 312 | e2750-2 | 416 |
|
121
|
| 313 | e750-1 | 252 |
|
122
|
| 314 | e750-2 | 309 |
|
123
|
| 315 | e750-3 | 346 |
|
124
|
| 316 | m1250-1 | 397 |
|
125
|
| 317 | m1250-2 | 396 |
|
126
|
| 318 | m1750-1 | 346 |
|
127
|
| 319 | m1750-2 | 247 |
|
128
|
| 320 | m1750-3 | 410 |
|
129
|
| 321 | m2250-1 | 390 |
|
130
|
| 322 | m2750-1 | 247 |
|
131
|
| 323 | m2750-2 | 220 |
|
132
|
| 324 | m2750-3 | 212 |
|
133
|
| 325 | m750-1 | 317 |
|
134
|
| 326 | m750-2 | 340 |
|
135
|
+--------+----------+----------+
|
136
|
37 rows in set (0.02 sec)
|
137
|
|
138
|
(b) method 2: sum `NoInd` (number of individuals). Valid for all individual-observations type plots
|
139
|
|
140
|
The following query tells me that this approach should be valid for all plots in this project:
|
141
|
|
142
|
SELECT NoInd, COUNT(*) AS observations
|
143
|
FROM plotObservations o JOIN plotMetadata p
|
144
|
ON o.PlotID=p.PlotID
|
145
|
WHERE project_id=2
|
146
|
GROUP BY NoInd;
|
147
|
+-------+--------------+
|
148
|
| NoInd | observations |
|
149
|
+-------+--------------+
|
150
|
| 1 | 11762 |
|
151
|
+-------+--------------+
|
152
|
1 row in set (0.03 sec)
|
153
|
|
154
|
Perfect. Now, let's count:
|
155
|
|
156
|
SELECT p.PlotID, p.SiteCode, SUM(NoInd) AS Individuals
|
157
|
FROM projects pr JOIN plotMetadata p JOIN plotObservations o
|
158
|
ON pr.project_id=p.project_id AND p.PlotID=o.PlotID
|
159
|
WHERE p.project_id=2
|
160
|
GROUP BY p.PlotID, p.SiteCode;
|
161
|
+--------+----------+-------------+
|
162
|
| PlotID | SiteCode | Individuals |
|
163
|
+--------+----------+-------------+
|
164
|
| 290 | c1000-1 | 321 |
|
165
|
| 291 | c1250-1 | 228 |
|
166
|
| 292 | c1750-1 | 270 |
|
167
|
| 293 | c1750-2 | 195 |
|
168
|
| 294 | c1750-3 | 274 |
|
169
|
| 295 | c2000-1 | 362 |
|
170
|
| 296 | c2000-2 | 352 |
|
171
|
| 297 | c2250-1 | 439 |
|
172
|
| 298 | c2750-1 | 189 |
|
173
|
| 299 | c2750-2 | 251 |
|
174
|
| 300 | c2750-3 | 248 |
|
175
|
| 301 | c500-1 | 273 |
|
176
|
| 302 | c750-1 | 298 |
|
177
|
| 303 | c750-2 | 303 |
|
178
|
| 304 | c750-3 | 295 |
|
179
|
| 305 | e1250-1 | 444 |
|
180
|
| 306 | e1750-1 | 313 |
|
181
|
| 307 | e1750-2 | 435 |
|
182
|
| 308 | e1750-3 | 402 |
|
183
|
| 309 | e2250-1 | 399 |
|
184
|
| 310 | e2250-2 | 316 |
|
185
|
| 311 | e2750-1 | 310 |
|
186
|
| 312 | e2750-2 | 416 |
|
187
|
| 313 | e750-1 | 252 |
|
188
|
| 314 | e750-2 | 309 |
|
189
|
| 315 | e750-3 | 346 |
|
190
|
| 316 | m1250-1 | 397 |
|
191
|
| 317 | m1250-2 | 396 |
|
192
|
| 318 | m1750-1 | 346 |
|
193
|
| 319 | m1750-2 | 247 |
|
194
|
| 320 | m1750-3 | 410 |
|
195
|
| 321 | m2250-1 | 390 |
|
196
|
| 322 | m2750-1 | 247 |
|
197
|
| 323 | m2750-2 | 220 |
|
198
|
| 324 | m2750-3 | 212 |
|
199
|
| 325 | m750-1 | 317 |
|
200
|
| 326 | m750-2 | 340 |
|
201
|
+--------+----------+-------------+
|
202
|
37 rows in set (0.04 sec)
|
203
|
|
204
|
Good, matches result using previous method.
|
205
|
|
206
|
Next, let's count individuals in a plot which uses aggregate counts of individuals
|
207
|
(lookup_MethodCode='species (stems)'). Method 1 isn't valid for such plots; we must use method 2.
|
208
|
|
209
|
First, what projects use this methodology?
|
210
|
|
211
|
SELECT DISTINCT pr.project_id, project_name, PlotMethod, m.MethodCode, m.Description
|
212
|
FROM projects pr JOIN plotMetadata p JOIN lookup_MethodCode m
|
213
|
ON pr.project_id=p.project_id AND p.MethodCode=m.MethodCode
|
214
|
WHERE m.MethodCode=8;
|
215
|
+------------+-------------------------+---------------------------------------+------------+-----------------+
|
216
|
| project_id | project_name | PlotMethod | MethodCode | Description |
|
217
|
+------------+-------------------------+---------------------------------------+------------+-----------------+
|
218
|
| 1 | Gentry Transect Dataset | 0.1 ha transect, stems >= 2.5 cm dbh | 8 | species (stems) |
|
219
|
+------------+-------------------------+---------------------------------------+------------+-----------------+
|
220
|
1 row in set (0.04 sec)
|
221
|
|
222
|
Gentry plots are the only ones. First, let's check to see if we have the expected distribution
|
223
|
of number of individuals:
|
224
|
|
225
|
SELECT NoInd, COUNT(*) AS observations
|
226
|
FROM plotObservations o JOIN plotMetadata p JOIN lookup_MethodCode m
|
227
|
ON o.PlotID=p.PlotID AND p.MethodCode=m.MethodCode
|
228
|
WHERE project_id=2
|
229
|
GROUP BY NoInd;
|
230
|
+-------+--------------+
|
231
|
| NoInd | observations |
|
232
|
+-------+--------------+
|
233
|
| NULL | 1 |
|
234
|
| 1 | 32823 |
|
235
|
| 2 | 6591 |
|
236
|
| 3 | 2445 |
|
237
|
| 4 | 1199 |
|
238
|
| 5 | 676 |
|
239
|
| 6 | 405 |
|
240
|
| 7 | 266 |
|
241
|
| 8 | 187 |
|
242
|
| 9 | 113 |
|
243
|
| 10 | 132 |
|
244
|
| 11 | 60 |
|
245
|
| 12 | 56 |
|
246
|
| 13 | 37 |
|
247
|
| 14 | 40 |
|
248
|
| 15 | 27 |
|
249
|
| 16 | 27 |
|
250
|
| 17 | 10 |
|
251
|
| 18 | 7 |
|
252
|
| 19 | 7 |
|
253
|
| 20 | 6 |
|
254
|
| 21 | 5 |
|
255
|
| 22 | 2 |
|
256
|
| 23 | 1 |
|
257
|
| 24 | 5 |
|
258
|
| 25 | 2 |
|
259
|
| 26 | 1 |
|
260
|
| 27 | 2 |
|
261
|
| 28 | 1 |
|
262
|
| 30 | 2 |
|
263
|
| 31 | 3 |
|
264
|
| 32 | 1 |
|
265
|
| 40 | 1 |
|
266
|
| 41 | 1 |
|
267
|
| 48 | 1 |
|
268
|
| 77 | 1 |
|
269
|
+-------+--------------+
|
270
|
36 rows in set (0.12 sec)
|
271
|
|
272
|
As expected, except for the one NULL value. Let's not worry about it. Let's do the count for the first 10 plots:
|
273
|
|
274
|
SELECT p.PlotID, p.SiteCode, SUM(NoInd) AS Individuals
|
275
|
FROM projects pr JOIN plotMetadata p JOIN plotObservations o
|
276
|
ON pr.project_id=p.project_id AND p.PlotID=o.PlotID
|
277
|
WHERE p.project_id=1
|
278
|
GROUP BY p.PlotID, p.SiteCode
|
279
|
LIMIT 10;
|
280
|
|
281
|
+--------+----------+-------------+
|
282
|
| PlotID | SiteCode | Individuals |
|
283
|
+--------+----------+-------------+
|
284
|
| 1 | ACHUPALL | 428 |
|
285
|
| 2 | ALLACHER | 248 |
|
286
|
| 3 | ALLPAHUA | 402 |
|
287
|
| 4 | ALTERDOC | 164 |
|
288
|
| 5 | ALTODEMI | 322 |
|
289
|
| 6 | ALTOSAPA | 391 |
|
290
|
| 7 | AMOTAPE | 395 |
|
291
|
| 8 | ANCHICAY | 412 |
|
292
|
| 9 | ANKARIF | 436 |
|
293
|
| 10 | ANTADO | 383 |
|
294
|
+--------+----------+-------------+
|
295
|
10 rows in set (0.00 sec)
|
296
|
|
297
|
5. Count of stems per plot
|
298
|
|
299
|
First, let's find out which methodologies are associated with stem measurements:
|
300
|
|
301
|
SELECT PlotMethod, MethodCode, Description, COUNT(project_id) as projects
|
302
|
FROM (
|
303
|
SELECT DISTINCT p.PlotMethod, p.MethodCode, p.Description, p.project_id
|
304
|
FROM (
|
305
|
SELECT project_id, PlotID, PlotMethod, m.MethodCode, m.Description
|
306
|
FROM plotMetadata p JOIN lookup_MethodCode m
|
307
|
ON p.MethodCode=m.MethodCode
|
308
|
) p JOIN plotObservations o JOIN stems s
|
309
|
ON p.PlotID=o.PlotID AND o.PlotObsID=s.PlotObsID
|
310
|
GROUP BY project_id
|
311
|
) AS a
|
312
|
GROUP BY PlotMethod, MethodCode, Description;
|
313
|
+-----------------------------------------------------------------------------------------------------------------+------------+-----------------+----------+
|
314
|
| PlotMethod | MethodCode | Description | projects |
|
315
|
+-----------------------------------------------------------------------------------------------------------------+------------+-----------------+----------+
|
316
|
| 0.01 ha, stems >= 10 cm dbh; 16 subplots of 10 x 10 m per plot, 4 rows (UU, U, S, SS), 4 columns (BB, B, T, TT) | 3 | individuals | 1 |
|
317
|
| 0.1 ha transect, stems >= 2.5 cm dbh | 3 | individuals | 9 |
|
318
|
| 0.1 ha transect, stems >= 2.5 cm dbh | 8 | species (stems) | 1 |
|
319
|
| 1 ha, stems >= 10 cm dbh | 3 | individuals | 7 |
|
320
|
+-----------------------------------------------------------------------------------------------------------------+------------+-----------------+----------+
|
321
|
4 rows in set (4.14 sec)
|
322
|
|
323
|
Normally, you'd expect only "individuals" methodology to allow collecting of stem information. That one project which uses counts of stems
|
324
|
per species ("species (stems)") is the Gentry plots. Just a quirk of the bad way in which the original data was recorded: it has individual stem
|
325
|
measurement, and counts of individuals per species, but no way to associate sets of stems with individuals trees. However, we can still
|
326
|
count stems even for these weird Gentry data.
|
327
|
|
328
|
Next, let's find a project which uses "individuals" methodology and has associated stem measurements.
|
329
|
|
330
|
SELECT DISTINCT pr.project_id, project_name
|
331
|
FROM projects pr JOIN plotMetadata p JOIN plotObservations o JOIN stems s
|
332
|
ON pr.project_id=p.project_id AND p.PlotID=o.PlotID AND o.PlotObsID=s.PlotObsID
|
333
|
WHERE p.MethodCode=3;
|
334
|
+------------+------------------------------------------------+
|
335
|
| project_id | project_name |
|
336
|
+------------+------------------------------------------------+
|
337
|
| 2 | Boyle Transects |
|
338
|
| 3 | OTS Transects |
|
339
|
| 5 | RAINFOR - 0.1 ha Madre de Dios, Peru |
|
340
|
| 6 | Noel Kempff Forest Plots |
|
341
|
| 10 | Enquist Lab Transect Dataset |
|
342
|
| 9 | Inventarios de Bosques de la Costa del Ecuador |
|
343
|
| 8 | Inventarios de Bosques en Ecuador |
|
344
|
| 12 | Cam Webb Borneo Plots |
|
345
|
| 13 | Pilon Lajas Treeplots Bolivia |
|
346
|
| 17 | Madidi Permanent Plots |
|
347
|
| 18 | SERBO Selva Seca Oaxaca |
|
348
|
| 19 | DeWalt Bolivia forest plots |
|
349
|
| 21 | La Selva Secondary Forest Plots |
|
350
|
| 22 | ACA Amazon Forest Inventories |
|
351
|
| 24 | Bonifacino Forest Transects |
|
352
|
| 25 | RAINFOR - 1 ha Peru |
|
353
|
| 14 | Madidi Transects |
|
354
|
+------------+------------------------------------------------+
|
355
|
17 rows in set (1.16 sec)
|
356
|
|
357
|
OK, Boyle Transect will do. Now, count stems for the first 10 plots:
|
358
|
|
359
|
SELECT p.PlotID, SiteName as plot, COUNT(*) AS stems
|
360
|
FROM plotMetadata p JOIN plotObservations o JOIN stems s
|
361
|
ON p.PlotID=o.PlotID AND o.PlotObsID=s.PlotObsID
|
362
|
WHERE p.project_id=2
|
363
|
GROUP BY p.PlotID, SiteName
|
364
|
LIMIT 10;
|
365
|
|
366
|
+--------+---------+-------+
|
367
|
| PlotID | plot | stems |
|
368
|
+--------+---------+-------+
|
369
|
| 290 | c1000-1 | 371 |
|
370
|
| 291 | c1250-1 | 258 |
|
371
|
| 292 | c1750-1 | 343 |
|
372
|
| 293 | c1750-2 | 285 |
|
373
|
| 294 | c1750-3 | 357 |
|
374
|
| 295 | c2000-1 | 424 |
|
375
|
| 296 | c2000-2 | 434 |
|
376
|
| 297 | c2250-1 | 525 |
|
377
|
| 298 | c2750-1 | 266 |
|
378
|
| 299 | c2750-2 | 324 |
|
379
|
+--------+---------+-------+
|
380
|
10 rows in set (0.13 sec)
|
381
|
|
382
|
|
383
|
6. Count of species (fully-identified species + morphospecies) per plot, Boyle Transects
|
384
|
|
385
|
SELECT p.PlotID, SiteName AS plot, COUNT(DISTINCT Family, Genus, Species) AS SpeciesCount
|
386
|
FROM plotMetadata p JOIN plotObservations o
|
387
|
ON p.PlotID=o.PlotID
|
388
|
WHERE project_id=2
|
389
|
GROUP BY p.PlotID, SiteName;
|
390
|
+--------+---------+--------------+
|
391
|
| PlotID | plot | SpeciesCount |
|
392
|
+--------+---------+--------------+
|
393
|
| 290 | c1000-1 | 133 |
|
394
|
| 291 | c1250-1 | 95 |
|
395
|
| 292 | c1750-1 | 86 |
|
396
|
| 293 | c1750-2 | 73 |
|
397
|
| 294 | c1750-3 | 82 |
|
398
|
| 295 | c2000-1 | 74 |
|
399
|
| 296 | c2000-2 | 62 |
|
400
|
| 297 | c2250-1 | 65 |
|
401
|
| 298 | c2750-1 | 24 |
|
402
|
| 299 | c2750-2 | 28 |
|
403
|
| 300 | c2750-3 | 39 |
|
404
|
| 301 | c500-1 | 118 |
|
405
|
| 302 | c750-1 | 130 |
|
406
|
| 303 | c750-2 | 115 |
|
407
|
| 304 | c750-3 | 128 |
|
408
|
| 305 | e1250-1 | 137 |
|
409
|
| 306 | e1750-1 | 113 |
|
410
|
| 307 | e1750-2 | 132 |
|
411
|
| 308 | e1750-3 | 105 |
|
412
|
| 309 | e2250-1 | 74 |
|
413
|
| 310 | e2250-2 | 101 |
|
414
|
| 311 | e2750-1 | 50 |
|
415
|
| 312 | e2750-2 | 52 |
|
416
|
| 313 | e750-1 | 101 |
|
417
|
| 314 | e750-2 | 115 |
|
418
|
| 315 | e750-3 | 119 |
|
419
|
| 316 | m1250-1 | 49 |
|
420
|
| 317 | m1250-2 | 62 |
|
421
|
| 318 | m1750-1 | 54 |
|
422
|
| 319 | m1750-2 | 58 |
|
423
|
| 320 | m1750-3 | 53 |
|
424
|
| 321 | m2250-1 | 42 |
|
425
|
| 322 | m2750-1 | 22 |
|
426
|
| 323 | m2750-2 | 15 |
|
427
|
| 324 | m2750-3 | 25 |
|
428
|
| 325 | m750-1 | 60 |
|
429
|
| 326 | m750-2 | 74 |
|
430
|
+--------+---------+--------------+
|
431
|
37 rows in set (0.03 sec)
|
432
|
|
433
|
7. List of all species (fully-identified species + morphospecies) for one plot
|
434
|
|
435
|
As an example, let's use the plot from above with fewest species:
|
436
|
|
437
|
SELECT DISTINCT p.PlotID, SiteName AS plot, Family, CONCAT_WS(' ',IFNULL(Genus,''), IFNULL(Species,'')) AS SpeciesName
|
438
|
FROM plotMetadata p JOIN plotObservations o
|
439
|
ON p.PlotID=o.PlotID
|
440
|
WHERE p.PlotID=298;
|
441
|
+--------+---------+-----------------+------------------------------+
|
442
|
| PlotID | plot | Family | SpeciesName |
|
443
|
+--------+---------+-----------------+------------------------------+
|
444
|
| 298 | c2750-1 | Aquifoliaceae | Ilex lamprophylla |
|
445
|
| 298 | c2750-1 | Araliaceae | Oreopanax xalapensis |
|
446
|
| 298 | c2750-1 | Araliaceae | Schefflera rodriguesiana |
|
447
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia fagaroides |
|
448
|
| 298 | c2750-1 | Ericaceae | Vaccinium poasanum |
|
449
|
| 298 | c2750-1 | Clethraceae | Clethra pyrogena |
|
450
|
| 298 | c2750-1 | Ericaceae | Cavendishia bracteata |
|
451
|
| 298 | c2750-1 | Melastomataceae | Miconia schnellii |
|
452
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia pinnata |
|
453
|
| 298 | c2750-1 | Myrsinaceae | Ardisia pleurobotrya |
|
454
|
| 298 | c2750-1 | Saxifragaceae | Escallonia myrtilloides |
|
455
|
| 298 | c2750-1 | Melastomataceae | Miconia longibracteata |
|
456
|
| 298 | c2750-1 | Rhamnaceae | Rhamnus oreodendron |
|
457
|
| 298 | c2750-1 | Araceae | Anthurium concinnatum |
|
458
|
| 298 | c2750-1 | Caprifoliaceae | Viburnum venustum |
|
459
|
| 298 | c2750-1 | Myrsinaceae | Myrsine pittieri |
|
460
|
| 298 | c2750-1 | Ericaceae | Disterigma humboldtii |
|
461
|
| 298 | c2750-1 | Winteraceae | Drimys granadensis |
|
462
|
| 298 | c2750-1 | Piperaceae | Piper pittieri |
|
463
|
| 298 | c2750-1 | Apiaceae | Myrrhidendron donnellsmithii |
|
464
|
| 298 | c2750-1 | Loranthaceae | Gaiadendron punctatum |
|
465
|
| 298 | c2750-1 | PTERIDOPHYTA | Cyathea suprastrigosa |
|
466
|
| 298 | c2750-1 | Solanaceae | Solanum vacciniiflorum |
|
467
|
| 298 | c2750-1 | Araliaceae | Dendropanax sp.1 |
|
468
|
+--------+---------+-----------------+------------------------------+
|
469
|
24 rows in set (0.01 sec)
|
470
|
|
471
|
9. List of fully-identified species only for one plot (using `name_status` as filter criterion)
|
472
|
|
473
|
Notice that one of the species above is a morphospecies (Dendropanax sp.1). Unfortunately, SALVIAS
|
474
|
keeps morphospecies strings in the same field as standard specific epithets. To exclude morphospecies
|
475
|
and get a list only of fully determined species (scientific names), we need to use the flag `name_status`.
|
476
|
Here are a few queries explaining what the column means:
|
477
|
|
478
|
SELECT name_status, count(*) FROM plotObservations GROUP BY name_status;
|
479
|
+-------------+----------+
|
480
|
| name_status | count(*) |
|
481
|
+-------------+----------+
|
482
|
| NULL | 1026 |
|
483
|
| 0 | 1841 |
|
484
|
| 1 | 374676 |
|
485
|
| 2 | 6940 |
|
486
|
| 3 | 42371 |
|
487
|
+-------------+----------+
|
488
|
5 rows in set (0.70 sec)
|
489
|
|
490
|
Too bad about the null values. Looks like `name_status` wasn't consistently used. Let's look at the
|
491
|
non-null values:
|
492
|
|
493
|
mysql> select name_status, Genus, Species from plotObservations where name_status=1 limit 10;
|
494
|
+-------------+--------------+-------------+
|
495
|
| name_status | Genus | Species |
|
496
|
+-------------+--------------+-------------+
|
497
|
| 1 | Geonoma | seleri |
|
498
|
| 1 | Tovomitopsis | allenii |
|
499
|
| 1 | Tovomitopsis | allenii |
|
500
|
| 1 | Celastrus | vulcanicola |
|
501
|
| 1 | Psychotria | sylvivaga |
|
502
|
| 1 | Tovomitopsis | allenii |
|
503
|
| 1 | Geonoma | seleri |
|
504
|
| 1 | Geonoma | seleri |
|
505
|
| 1 | Geonoma | seleri |
|
506
|
| 1 | Geonoma | seleri |
|
507
|
+-------------+--------------+-------------+
|
508
|
10 rows in set (0.00 sec)
|
509
|
|
510
|
The above are standard scientific names.
|
511
|
|
512
|
mysql> select name_status, Genus, Species from plotObservations where name_status=2 limit 10;
|
513
|
+-------------+--------------+----------+
|
514
|
| name_status | Genus | Species |
|
515
|
+-------------+--------------+----------+
|
516
|
| 2 | gen_indet. | sp. |
|
517
|
| 2 | gen_indet. | sp. |
|
518
|
| 2 | gen_indet. | sp. |
|
519
|
| 2 | Elaeocarpus | sp. nov. |
|
520
|
| 2 | Cryptocarya | sp. nov. |
|
521
|
| 2 | Planchonella | sp. nov. |
|
522
|
| 2 | Planchonella | sp. nov. |
|
523
|
| 2 | Planchonella | sp. nov. |
|
524
|
| 2 | Planchonella | sp. nov. |
|
525
|
| 2 | Planchonella | sp. nov. |
|
526
|
+-------------+--------------+----------+
|
527
|
10 rows in set (0.03 sec)
|
528
|
|
529
|
The above are essentially "undefined" species, either definitely undescribed (sp. nov), or "who knows"
|
530
|
(sp.). Not quite the same as morphospecies in that we do not know if two records labeled as "Miconia
|
531
|
sp." refer to the same thing.
|
532
|
|
533
|
mysql> select name_status, Genus, Species from plotObservations where name_status=3 limit 10;
|
534
|
+-------------+---------+---------+
|
535
|
| name_status | Genus | Species |
|
536
|
+-------------+---------+---------+
|
537
|
| 3 | Ardisia | sp.4 |
|
538
|
| 3 | Ardisia | sp.1 |
|
539
|
| 3 | Ardisia | sp.1 |
|
540
|
| 3 | Ardisia | sp.1 |
|
541
|
| 3 | Eugenia | sp.1 |
|
542
|
| 3 | Ardisia | sp.4 |
|
543
|
| 3 | Miconia | sp.6 |
|
544
|
| 3 | Ardisia | sp.1 |
|
545
|
| 3 | Miconia | sp.6 |
|
546
|
| 3 | Ardisia | sp.3 |
|
547
|
+-------------+---------+---------+
|
548
|
10 rows in set (0.00 sec)
|
549
|
|
550
|
The above are morphospecies. Unidentified formally (no complete scientific name), but the data
|
551
|
collector was asserting that all records of, say, Ardisia sp.4, refer to the same species (only
|
552
|
within a given plot. Between plots we don't know, or at least there is insufficient metadata in
|
553
|
SALVIAS to determine this.
|
554
|
|
555
|
mysql> select name_status, Genus, Species from plotObservations where name_status=0 limit 10;
|
556
|
+-------------+----------+-----------+
|
557
|
| name_status | Genus | Species |
|
558
|
+-------------+----------+-----------+
|
559
|
| 0 | Faramea | cogolloi |
|
560
|
| 0 | Faramea | cogolloi |
|
561
|
| 0 | Faramea | cogolloi |
|
562
|
| 0 | Faramea | cogolloi |
|
563
|
| 0 | Faramea | cogolloi |
|
564
|
| 0 | Dussia | montana |
|
565
|
| 0 | Siparuna | tecaphora |
|
566
|
| 0 | Siparuna | tecaphora |
|
567
|
| 0 | Siparuna | tecaphora |
|
568
|
| 0 | Eleagnus | CONFORTA |
|
569
|
+-------------+----------+-----------+
|
570
|
10 rows in set (0.02 sec)
|
571
|
|
572
|
The above are harder to explain. Basically, SALVIAS is recognizing that they are intended to be
|
573
|
scientific names (not morphospecies) but they could not be matched to any published name in
|
574
|
Tropicos or taxonomic databases such as IPNI. So, they are provisionally scientific names.
|
575
|
|
576
|
So, let's have a look at the name_status flag for that plot we queried above:
|
577
|
|
578
|
SELECT DISTINCT p.PlotID, SiteName AS plot, Family,
|
579
|
CONCAT_WS(' ',IFNULL(Genus,''), IFNULL(Species,'')) AS SpeciesName, name_status
|
580
|
FROM plotMetadata p JOIN plotObservations o
|
581
|
ON p.PlotID=o.PlotID
|
582
|
WHERE p.PlotID=298;
|
583
|
+--------+---------+-----------------+------------------------------+-------------+
|
584
|
| PlotID | plot | Family | SpeciesName | name_status |
|
585
|
+--------+---------+-----------------+------------------------------+-------------+
|
586
|
| 298 | c2750-1 | Aquifoliaceae | Ilex lamprophylla | 1 |
|
587
|
| 298 | c2750-1 | Araliaceae | Oreopanax xalapensis | 1 |
|
588
|
| 298 | c2750-1 | Araliaceae | Schefflera rodriguesiana | 1 |
|
589
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia fagaroides | 1 |
|
590
|
| 298 | c2750-1 | Ericaceae | Vaccinium poasanum | 1 |
|
591
|
| 298 | c2750-1 | Clethraceae | Clethra pyrogena | 1 |
|
592
|
| 298 | c2750-1 | Ericaceae | Cavendishia bracteata | 1 |
|
593
|
| 298 | c2750-1 | Melastomataceae | Miconia schnellii | 1 |
|
594
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia pinnata | 1 |
|
595
|
| 298 | c2750-1 | Myrsinaceae | Ardisia pleurobotrya | 1 |
|
596
|
| 298 | c2750-1 | Saxifragaceae | Escallonia myrtilloides | 1 |
|
597
|
| 298 | c2750-1 | Melastomataceae | Miconia longibracteata | 1 |
|
598
|
| 298 | c2750-1 | Rhamnaceae | Rhamnus oreodendron | 1 |
|
599
|
| 298 | c2750-1 | Araceae | Anthurium concinnatum | 1 |
|
600
|
| 298 | c2750-1 | Caprifoliaceae | Viburnum venustum | 1 |
|
601
|
| 298 | c2750-1 | Myrsinaceae | Myrsine pittieri | 1 |
|
602
|
| 298 | c2750-1 | Ericaceae | Disterigma humboldtii | 1 |
|
603
|
| 298 | c2750-1 | Winteraceae | Drimys granadensis | 1 |
|
604
|
| 298 | c2750-1 | Piperaceae | Piper pittieri | 1 |
|
605
|
| 298 | c2750-1 | Apiaceae | Myrrhidendron donnellsmithii | 1 |
|
606
|
| 298 | c2750-1 | Loranthaceae | Gaiadendron punctatum | 1 |
|
607
|
| 298 | c2750-1 | PTERIDOPHYTA | Cyathea suprastrigosa | 1 |
|
608
|
| 298 | c2750-1 | Solanaceae | Solanum vacciniiflorum | 1 |
|
609
|
| 298 | c2750-1 | Araliaceae | Dendropanax sp.1 | 3 |
|
610
|
+--------+---------+-----------------+------------------------------+-------------+
|
611
|
24 rows in set (0.00 sec)
|
612
|
|
613
|
So, finally, to get a list of proper scientific names only, we use name_status=1 as our criterion:
|
614
|
|
615
|
SELECT DISTINCT p.PlotID, SiteName AS plot, Family,
|
616
|
CONCAT_WS(' ',IFNULL(Genus,''), IFNULL(Species,'')) AS SpeciesName, name_status
|
617
|
FROM plotMetadata p JOIN plotObservations o
|
618
|
ON p.PlotID=o.PlotID
|
619
|
WHERE p.PlotID=298 AND name_status=1;
|
620
|
+--------+---------+-----------------+------------------------------+-------------+
|
621
|
| PlotID | plot | Family | SpeciesName | name_status |
|
622
|
+--------+---------+-----------------+------------------------------+-------------+
|
623
|
| 298 | c2750-1 | Aquifoliaceae | Ilex lamprophylla | 1 |
|
624
|
| 298 | c2750-1 | Araliaceae | Oreopanax xalapensis | 1 |
|
625
|
| 298 | c2750-1 | Araliaceae | Schefflera rodriguesiana | 1 |
|
626
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia fagaroides | 1 |
|
627
|
| 298 | c2750-1 | Ericaceae | Vaccinium poasanum | 1 |
|
628
|
| 298 | c2750-1 | Clethraceae | Clethra pyrogena | 1 |
|
629
|
| 298 | c2750-1 | Ericaceae | Cavendishia bracteata | 1 |
|
630
|
| 298 | c2750-1 | Melastomataceae | Miconia schnellii | 1 |
|
631
|
| 298 | c2750-1 | Cunoniaceae | Weinmannia pinnata | 1 |
|
632
|
| 298 | c2750-1 | Myrsinaceae | Ardisia pleurobotrya | 1 |
|
633
|
| 298 | c2750-1 | Saxifragaceae | Escallonia myrtilloides | 1 |
|
634
|
| 298 | c2750-1 | Melastomataceae | Miconia longibracteata | 1 |
|
635
|
| 298 | c2750-1 | Rhamnaceae | Rhamnus oreodendron | 1 |
|
636
|
| 298 | c2750-1 | Araceae | Anthurium concinnatum | 1 |
|
637
|
| 298 | c2750-1 | Caprifoliaceae | Viburnum venustum | 1 |
|
638
|
| 298 | c2750-1 | Myrsinaceae | Myrsine pittieri | 1 |
|
639
|
| 298 | c2750-1 | Ericaceae | Disterigma humboldtii | 1 |
|
640
|
| 298 | c2750-1 | Winteraceae | Drimys granadensis | 1 |
|
641
|
| 298 | c2750-1 | Piperaceae | Piper pittieri | 1 |
|
642
|
| 298 | c2750-1 | Apiaceae | Myrrhidendron donnellsmithii | 1 |
|
643
|
| 298 | c2750-1 | Loranthaceae | Gaiadendron punctatum | 1 |
|
644
|
| 298 | c2750-1 | PTERIDOPHYTA | Cyathea suprastrigosa | 1 |
|
645
|
| 298 | c2750-1 | Solanaceae | Solanum vacciniiflorum | 1 |
|
646
|
+--------+---------+-----------------+------------------------------+-------------+
|
647
|
23 rows in set (0.00 sec)
|
648
|
|
649
|
If you weren't so strict and were willing to include unverified scientific names, you could also
|
650
|
use the criterion "name_status=1 OR name_status=0".
|
651
|
|
652
|
10. Count of individuals in each subplot within a single plot (individual-observation plots only)
|
653
|
|
654
|
In SALVIAS, subplot codes are in the column `Line` in the table `plotObservations`.
|
655
|
|
656
|
(a) Method one, for 'individuals' method plots only. I won't do a lookup here, as we already
|
657
|
know that all Boyle Transects use this methodology.
|
658
|
|
659
|
SELECT p.PlotID, SiteCode AS plot, o.Line as subplot, COUNT(*) AS individuals
|
660
|
FROM plotMetadata p JOIN plotObservations o
|
661
|
ON p.PlotID=o.PlotID
|
662
|
WHERE p.PlotID=298
|
663
|
GROUP BY p.PlotID, plot, subplot;
|
664
|
+--------+---------+---------+-------------+
|
665
|
| PlotID | plot | subplot | individuals |
|
666
|
+--------+---------+---------+-------------+
|
667
|
| 298 | c2750-1 | 1 | 14 |
|
668
|
| 298 | c2750-1 | 10 | 20 |
|
669
|
| 298 | c2750-1 | 2 | 29 |
|
670
|
| 298 | c2750-1 | 3 | 26 |
|
671
|
| 298 | c2750-1 | 4 | 26 |
|
672
|
| 298 | c2750-1 | 5 | 19 |
|
673
|
| 298 | c2750-1 | 6 | 12 |
|
674
|
| 298 | c2750-1 | 7 | 8 |
|
675
|
| 298 | c2750-1 | 8 | 20 |
|
676
|
| 298 | c2750-1 | 9 | 15 |
|
677
|
+--------+---------+---------+-------------+
|
678
|
10 rows in set (0.00 sec)
|
679
|
|
680
|
(b) Method 2, for 'individuals' method plots AND 'species (stems)' method plots. We MUST use
|
681
|
this query method for 'species (stems)' plots (= the Gentry plots, see above). First, for
|
682
|
the same plot as above:
|
683
|
|
684
|
SELECT p.PlotID, SiteCode AS plot, o.Line as subplot, SUM(NoInd) AS individuals
|
685
|
FROM plotMetadata p JOIN plotObservations o
|
686
|
ON p.PlotID=o.PlotID
|
687
|
WHERE p.PlotID=298
|
688
|
GROUP BY p.PlotID, plot, subplot;
|
689
|
+--------+---------+---------+-------------+
|
690
|
| PlotID | plot | subplot | individuals |
|
691
|
+--------+---------+---------+-------------+
|
692
|
| 298 | c2750-1 | 1 | 14 |
|
693
|
| 298 | c2750-1 | 10 | 20 |
|
694
|
| 298 | c2750-1 | 2 | 29 |
|
695
|
| 298 | c2750-1 | 3 | 26 |
|
696
|
| 298 | c2750-1 | 4 | 26 |
|
697
|
| 298 | c2750-1 | 5 | 19 |
|
698
|
| 298 | c2750-1 | 6 | 12 |
|
699
|
| 298 | c2750-1 | 7 | 8 |
|
700
|
| 298 | c2750-1 | 8 | 20 |
|
701
|
| 298 | c2750-1 | 9 | 15 |
|
702
|
+--------+---------+---------+-------------+
|
703
|
10 rows in set (0.01 sec)
|
704
|
|
705
|
Now a Gentry plot. I happen to know the plot #1 is a Gentry plot, so will use that as an
|
706
|
example of a 'species (stems)' plot:
|
707
|
|
708
|
SELECT p.PlotID, SiteCode AS plot, o.Line as subplot, SUM(NoInd) AS individuals
|
709
|
FROM plotMetadata p JOIN plotObservations o
|
710
|
ON p.PlotID=o.PlotID
|
711
|
WHERE p.PlotID=1
|
712
|
GROUP BY p.PlotID, plot, subplot;
|
713
|
+--------+----------+---------+-------------+
|
714
|
| PlotID | plot | subplot | individuals |
|
715
|
+--------+----------+---------+-------------+
|
716
|
| 1 | ACHUPALL | 1 | 53 |
|
717
|
| 1 | ACHUPALL | 2 | 62 |
|
718
|
| 1 | ACHUPALL | 3 | 72 |
|
719
|
| 1 | ACHUPALL | 4 | 83 |
|
720
|
| 1 | ACHUPALL | 5 | 71 |
|
721
|
| 1 | ACHUPALL | 6 | 87 |
|
722
|
+--------+----------+---------+-------------+
|
723
|
6 rows in set (0.00 sec)
|
724
|
|
725
|
Hmm, so Gentry's plot ACHUPALL only had 6 lines. Actually an important bit of metadata I did not
|
726
|
know before. Probably a good idea to exclude this plot from analyses given that it is incomplete.
|
727
|
|
728
|
11. List of species and their percent cover for a single aggregate observation plot
|
729
|
|
730
|
This shows how to deal with the type of aggregate observation plot which uses percent cover,
|
731
|
not counts of individuals. Recall from above that the MethodCode for percent cover plots is 1.
|
732
|
First, how many plots use this methodology?
|
733
|
|
734
|
SELECT COUNT(*) FROM plotMetadata WHERE MethodCode=1;
|
735
|
+----------+
|
736
|
| COUNT(*) |
|
737
|
+----------+
|
738
|
| 12962 |
|
739
|
+----------+
|
740
|
1 row in set (0.01 sec)
|
741
|
|
742
|
Tons. OK, let's get one:
|
743
|
|
744
|
SELECT PlotID FROM plotMetadata WHERE MethodCode=1 LIMIT 1;
|
745
|
+--------+
|
746
|
| PlotID |
|
747
|
+--------+
|
748
|
| 24589 |
|
749
|
+--------+
|
750
|
1 row in set (0.00 sec)
|
751
|
|
752
|
Now get percent cover for all the species:
|
753
|
|
754
|
SELECT p.PlotID, SiteCode AS plot, Family,
|
755
|
CONCAT_WS(' ',IFNULL(Genus,''), IFNULL(Species,'')) AS SpeciesName, cover_percent
|
756
|
FROM plotMetadata p JOIN plotObservations o
|
757
|
ON p.PlotID=o.PlotID
|
758
|
WHERE p.PlotID=24589;
|
759
|
+--------+----------+-----------------+------------------------+---------------+
|
760
|
| PlotID | plot | Family | SpeciesName | cover_percent |
|
761
|
+--------+----------+-----------------+------------------------+---------------+
|
762
|
| 24589 | INW33656 | Caprifoliaceae | Symphoricarpos albus | 3.00 |
|
763
|
| 24589 | INW33656 | Caprifoliaceae | Sambucus cerulea | 1.00 |
|
764
|
| 24589 | INW33656 | Rosaceae | Rosa woodsii | 3.00 |
|
765
|
| 24589 | INW33656 | Pyrolaceae | Pterospora andromedea | 1.00 |
|
766
|
| 24589 | INW33656 | Pinaceae | Pseudotsuga menziesii | 30.00 |
|
767
|
| 24589 | INW33656 | Rosaceae | Prunus emarginata | 1.00 |
|
768
|
| 24589 | INW33656 | Pinaceae | Pinus ponderosa | 40.00 |
|
769
|
| 24589 | INW33656 | Saxifragaceae | Philadelphus lewisii | 10.00 |
|
770
|
| 24589 | INW33656 | Apiaceae | Osmorhiza chilensis | 10.00 |
|
771
|
| 24589 | INW33656 | Caryophyllaceae | Moehringia macrophylla | 3.00 |
|
772
|
| 24589 | INW33656 | Boraginaceae | Lithospermum ruderale | 1.00 |
|
773
|
| 24589 | INW33656 | Rosaceae | Holodiscus discolor | 3.00 |
|
774
|
| 24589 | INW33656 | Asteraceae | Hieracium scouleri | 3.00 |
|
775
|
| 24589 | INW33656 | Asteraceae | Hieracium albiflorum | 3.00 |
|
776
|
| 24589 | INW33656 | Orchidaceae | Goodyera oblongifolia | 3.00 |
|
777
|
| 24589 | INW33656 | Rubiaceae | Galium triflorum | 3.00 |
|
778
|
| 24589 | INW33656 | Poaceae | Festuca occidentalis | 3.00 |
|
779
|
| 24589 | INW33656 | Poaceae | Elymus glaucus | 10.00 |
|
780
|
| 24589 | INW33656 | Cyperaceae | Carex geyeri | 20.00 |
|
781
|
| 24589 | INW33656 | Poaceae | Bromopsis vulgaris | 3.00 |
|
782
|
| 24589 | INW33656 | Berberidaceae | Berberis aquifolium | 10.00 |
|
783
|
| 24589 | INW33656 | Aceraceae | Acer macrophyllum | 1.00 |
|
784
|
| 24589 | INW33656 | Aceraceae | Acer glabrum | 3.00 |
|
785
|
+--------+----------+-----------------+------------------------+---------------+
|
786
|
23 rows in set (0.00 sec)
|
787
|
|
788
|
In theory, this should be all that's needed. No summing. Unless of course the plot has subplots.
|
789
|
That would be something to check before running a query such as this one.
|
790
|
|
791
|
12. List of locality and environmental details for all plots in a single project
|
792
|
|
793
|
Here's what the basic metadata should look like for the first few Gentry plots:
|
794
|
|
795
|
SELECT p.PlotID, p.SiteCode as plot, Country, PolDiv1 AS stateProvince, pol2 AS countyParish,
|
796
|
LatDec as latitude, LongDec as longitude, Elev as elevation
|
797
|
FROM projects pr JOIN plotMetadata p
|
798
|
ON pr.project_id=p.project_id
|
799
|
WHERE pr.project_id=1
|
800
|
LIMIT 20;
|
801
|
+--------+----------+------------------+---------------+--------------+-----------+-----------+-----------+
|
802
|
| PlotID | plot | Country | stateProvince | countyParish | latitude | longitude | elevation |
|
803
|
+--------+----------+------------------+---------------+--------------+-----------+-----------+-----------+
|
804
|
| 1 | ACHUPALL | Ecuador | NULL | NULL | -3.45 | -78.3667 | 2100 |
|
805
|
| 2 | ALLACHER | Germany | NULL | NULL | 48.0667 | 11.5 | 530 |
|
806
|
| 3 | ALLPAHUA | Peru | NULL | NULL | -3.95 | -73.4167 | 155 |
|
807
|
| 4 | ALTERDOC | Brazil | NULL | NULL | -2.5 | -54.9667 | 50 |
|
808
|
| 5 | ALTODEMI | Colombia | NULL | NULL | 10.9167 | -73.8333 | 1180 |
|
809
|
| 6 | ALTOSAPA | Colombia | NULL | NULL | 7.16667 | -75.9 | 2660 |
|
810
|
| 7 | AMOTAPE | Peru | NULL | NULL | -4.15 | -80.6167 | 830 |
|
811
|
| 8 | ANCHICAY | Colombia | NULL | NULL | 3.75 | -76.8333 | 300 |
|
812
|
| 9 | ANKARIF | Madagascar | NULL | NULL | -16.3167 | 46.8167 | 80 |
|
813
|
| 10 | ANTADO | Colombia | NULL | NULL | 7.25 | -75.9167 | 1560 |
|
814
|
| 11 | ARARACUA | Colombia | NULL | NULL | -0.416667 | -72.3333 | 200 |
|
815
|
| 12 | ARCATING | Colombia | NULL | NULL | -0.416667 | -72.3167 | 250 |
|
816
|
| 13 | AVALANCH | India | NULL | NULL | 11.3 | 76.5833 | 2100 |
|
817
|
| 14 | BABLERSP | USA | Missouri | St. Louis | 38.5333 | -90.6667 | 150 |
|
818
|
| 15 | BAITETE | Papua New Guinea | NULL | NULL | -5.16667 | 145.8 | 200 |
|
819
|
| 16 | BAKOSAR | Malaysia | NULL | NULL | 1.75 | 110.417 | 90 |
|
820
|
| 17 | BANKAMP | USA | Ohio | Belmont | 40.05 | -81.0167 | 250 |
|
821
|
| 18 | BANYONG | Cameroun | NULL | NULL | 5 | 9.16667 | 420 |
|
822
|
| 19 | BELEM | Brazil | NULL | NULL | -1.5 | -47.9833 | 20 |
|
823
|
| 20 | BELINGA | Gabon | NULL | NULL | 1.15 | 13.2 | 750 |
|
824
|
+--------+----------+------------------+---------------+--------------+-----------+-----------+-----------+
|
825
|
20 rows in set (0.00 sec)
|
826
|
|
827
|
13. Display data access conditions (embargo levels) for individual plots
|
828
|
|
829
|
Final thing. There is an extremely important column in the plot table in SALVIAS which indicates
|
830
|
the allowed level of access for an individual plot. It is called "AccessCode", and here is a
|
831
|
count of the number of plots with each value:
|
832
|
|
833
|
SELECT AccessCode, COUNT(*)
|
834
|
FROM plotMetadata
|
835
|
GROUP BY AccessCode;
|
836
|
+------------+----------+
|
837
|
| AccessCode | COUNT(*) |
|
838
|
+------------+----------+
|
839
|
| 1 | 5 |
|
840
|
| 2 | 236 |
|
841
|
| 3 | 13420 |
|
842
|
+------------+----------+
|
843
|
3 rows in set (0.02 sec)
|
844
|
|
845
|
There is no information anywhre in the `salvias_plots` database to tell you what AccessCode means.
|
846
|
That is because it is used by a separate database, `salvias_users`, to control who can download
|
847
|
what. However, there is a description of this code on the SALVIAS website, at
|
848
|
http://www.salvias.net/eula/eula1.html:
|
849
|
|
850
|
User Can Access:
|
851
|
Level Description Description Data
|
852
|
1 Completely Restricted False False
|
853
|
2 Plot Description Only True False
|
854
|
3 Full Access True True
|
855
|
|
856
|
So, level 3 plots can be downloaded by anyone (although they are still required to offer the data
|
857
|
owner to option of co-authorship should they publish; SALVIAS records user name and timestamp
|
858
|
of any download and reports to the data owner).
|
859
|
|
860
|
For level 2 plots, the metadata only is visible on SALVIAS. Anyone wishing to use the data must
|
861
|
contact the data owner to obtain the full data.
|
862
|
|
863
|
Level 3 plots are completely hidden to the public, including metadata. They are visible only
|
864
|
to the data owner and database administrators.
|
865
|
|
866
|
`AccessCode` defines the default access for a given plot. This is the access a new user will have
|
867
|
when she signs on. However, the data owner can assign different access levels to individual users.
|
868
|
|
869
|
Please be careful with plots with AccessCode 1 or 2, especially level 1. Plots with AccessCode=1
|
870
|
should not be shared with anyone. We do not have permission to do so. Below is a bit of metadata
|
871
|
about the level 1 plots and their owners:
|
872
|
|
873
|
SELECT pr.project_id, project_name, project_pi, allow_download_all, PlotID, SiteCode, Country
|
874
|
FROM projects pr JOIN plotMetadata p
|
875
|
ON pr.project_id=p.project_id
|
876
|
WHERE p.AccessCode=1;
|
877
|
+------------+-------------------------+-------------+--------------------+--------+------------+---------+
|
878
|
| project_id | project_name | project_pi | allow_download_all | PlotID | SiteCode | Country |
|
879
|
+------------+-------------------------+-------------+--------------------+--------+------------+---------+
|
880
|
| 16 | nsf_example | nsf_salvias | 1 | 3778 | nsf_1 | Bolivia |
|
881
|
| 16 | nsf_example | nsf_salvias | 1 | 3779 | nsf_2 | USA |
|
882
|
| 18 | SERBO Selva Seca Oaxaca | boyle_admin | 0 | 3791 | La Cotorra | Mexico |
|
883
|
| 18 | SERBO Selva Seca Oaxaca | boyle_admin | 0 | 3792 | La Bamba | Mexico |
|
884
|
| 18 | SERBO Selva Seca Oaxaca | boyle_admin | 0 | 3793 | El Chorro | Mexico |
|
885
|
+------------+-------------------------+-------------+--------------------+--------+------------+---------+
|
886
|
5 rows in set (0.05 sec)
|
887
|
|
888
|
The first two plots are just examples to show how the access controls work. The last three however
|
889
|
belong to a friend of mine. She has not yet published them, and we are not allowed to show them to
|
890
|
anyone until she does and gives us the green light.
|
891
|
|
892
|
|
893
|
|
894
|
|
895
|
|