1
|
--
|
2
|
-- PostgreSQL database dump
|
3
|
--
|
4
|
|
5
|
SET statement_timeout = 0;
|
6
|
SET lock_timeout = 0;
|
7
|
SET client_encoding = 'UTF8';
|
8
|
SET standard_conforming_strings = on;
|
9
|
SET check_function_bodies = false;
|
10
|
SET client_min_messages = warning;
|
11
|
|
12
|
--
|
13
|
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
|
14
|
--
|
15
|
|
16
|
--CREATE SCHEMA "TNRS";
|
17
|
|
18
|
|
19
|
--
|
20
|
-- Name: SCHEMA "TNRS"; Type: COMMENT; Schema: -; Owner: -
|
21
|
--
|
22
|
|
23
|
COMMENT ON SCHEMA "TNRS" IS '
|
24
|
IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
|
25
|
on vegbiendev:
|
26
|
# back up existing TNRS schema (in case of an accidental incorrect change):
|
27
|
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
|
28
|
$ svn up
|
29
|
$ svn di
|
30
|
# make the changes shown in the diff
|
31
|
## to change column types:
|
32
|
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
|
33
|
(''col'', ''new_type'')
|
34
|
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
|
35
|
$ rm=1 inputs/.TNRS/schema.sql.run
|
36
|
# repeat until `svn di` shows no diff
|
37
|
# back up new TNRS schema:
|
38
|
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
|
39
|
';
|
40
|
|
41
|
|
42
|
SET search_path = "TNRS", pg_catalog;
|
43
|
|
44
|
--
|
45
|
-- Name: MatchedTaxon_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
46
|
--
|
47
|
|
48
|
CREATE FUNCTION "MatchedTaxon_modify"(view_query text DEFAULT NULL::text) RETURNS void
|
49
|
LANGUAGE sql
|
50
|
AS $_$
|
51
|
SELECT util.recreate_view('"TNRS"."MatchedTaxon"', $1, $$
|
52
|
-- **IMPORTANT**: keep these updated as described in the views' comments
|
53
|
|
54
|
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS
|
55
|
SELECT *
|
56
|
FROM "TNRS"."MatchedTaxon"
|
57
|
WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
|
58
|
$$||util.mk_set_relation_metadata('"TNRS"."ValidMatchedTaxon"')||$$
|
59
|
|
60
|
CREATE VIEW "TNRS".taxon_scrub AS
|
61
|
SELECT *,
|
62
|
CASE
|
63
|
WHEN "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'family'::text THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "ValidMatchedTaxon"."morphospeciesSuffix")
|
64
|
WHEN "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'genus'::text THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, "ValidMatchedTaxon"."morphospeciesSuffix")
|
65
|
ELSE ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet
|
66
|
END AS scrubbed_morphospecies_binomial
|
67
|
FROM "TNRS"."ValidMatchedTaxon"
|
68
|
LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
|
69
|
$$||util.mk_set_relation_metadata('"TNRS".taxon_scrub')||$$
|
70
|
$$);
|
71
|
$_$;
|
72
|
|
73
|
|
74
|
--
|
75
|
-- Name: FUNCTION "MatchedTaxon_modify"(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
|
76
|
--
|
77
|
|
78
|
COMMENT ON FUNCTION "MatchedTaxon_modify"(view_query text) IS '
|
79
|
usage:
|
80
|
SELECT "TNRS"."MatchedTaxon_modify"($$
|
81
|
SELECT *, __ AS accepted_morphospecies_binomial
|
82
|
FROM __
|
83
|
$$);
|
84
|
|
85
|
idempotent
|
86
|
';
|
87
|
|
88
|
|
89
|
--
|
90
|
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
|
91
|
--
|
92
|
|
93
|
CREATE FUNCTION batch__fill() RETURNS trigger
|
94
|
LANGUAGE plpgsql
|
95
|
AS $$
|
96
|
BEGIN
|
97
|
new.id_by_time = new.time_submitted;
|
98
|
new.id = COALESCE(new.id, new.id_by_time);
|
99
|
RETURN new;
|
100
|
END;
|
101
|
$$;
|
102
|
|
103
|
|
104
|
--
|
105
|
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
106
|
--
|
107
|
|
108
|
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
|
109
|
LANGUAGE sql STABLE STRICT
|
110
|
AS $_$
|
111
|
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
|
112
|
$_$;
|
113
|
|
114
|
|
115
|
--
|
116
|
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
117
|
--
|
118
|
|
119
|
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
|
120
|
LANGUAGE sql STABLE STRICT
|
121
|
AS $_$
|
122
|
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
|
123
|
$_$;
|
124
|
|
125
|
|
126
|
--
|
127
|
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
|
128
|
--
|
129
|
|
130
|
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
|
131
|
LANGUAGE sql IMMUTABLE
|
132
|
AS $_$
|
133
|
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
|
134
|
"taxonomic_status should be accepted instead of synonym when an accepted name is
|
135
|
available (this is not always the case when a name is marked as a synonym)" */
|
136
|
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
|
137
|
$_$;
|
138
|
|
139
|
|
140
|
--
|
141
|
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
142
|
--
|
143
|
|
144
|
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
|
145
|
LANGUAGE sql IMMUTABLE
|
146
|
AS $_$
|
147
|
SELECT $1 != ANY("TNRS".unsafe_taxon_names())
|
148
|
$_$;
|
149
|
|
150
|
|
151
|
--
|
152
|
-- Name: taxon_scrub_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
153
|
--
|
154
|
|
155
|
CREATE FUNCTION taxon_scrub_modify(view_query text DEFAULT NULL::text) RETURNS void
|
156
|
LANGUAGE sql
|
157
|
AS $_$
|
158
|
SELECT util.recreate_view('"TNRS".taxon_scrub', $1);
|
159
|
$_$;
|
160
|
|
161
|
|
162
|
--
|
163
|
-- Name: FUNCTION taxon_scrub_modify(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
|
164
|
--
|
165
|
|
166
|
COMMENT ON FUNCTION taxon_scrub_modify(view_query text) IS '
|
167
|
usage:
|
168
|
SELECT "TNRS".taxon_scrub_modify($$
|
169
|
SELECT *, __ AS scrubbed_morphospecies_binomial
|
170
|
FROM "TNRS"."ValidMatchedTaxon"
|
171
|
LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
|
172
|
$$);
|
173
|
|
174
|
idempotent
|
175
|
';
|
176
|
|
177
|
|
178
|
--
|
179
|
-- Name: tnrs__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
|
180
|
--
|
181
|
|
182
|
CREATE FUNCTION tnrs__batch_begin() RETURNS trigger
|
183
|
LANGUAGE plpgsql
|
184
|
AS $$
|
185
|
BEGIN
|
186
|
PERFORM util.seq__reset('pg_temp.tnrs__match_num__seq', 0);
|
187
|
RETURN NULL;
|
188
|
END;
|
189
|
$$;
|
190
|
|
191
|
|
192
|
--
|
193
|
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
|
194
|
--
|
195
|
|
196
|
CREATE FUNCTION tnrs__match_num__fill() RETURNS trigger
|
197
|
LANGUAGE plpgsql
|
198
|
AS $$
|
199
|
BEGIN
|
200
|
IF new.match_num IS NULL THEN
|
201
|
new.match_num = "TNRS".tnrs__match_num__next();
|
202
|
END IF;
|
203
|
RETURN new;
|
204
|
END;
|
205
|
$$;
|
206
|
|
207
|
|
208
|
--
|
209
|
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
|
210
|
--
|
211
|
|
212
|
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
|
213
|
LANGUAGE sql
|
214
|
AS $$
|
215
|
SELECT nextval('pg_temp.tnrs__match_num__seq');
|
216
|
$$;
|
217
|
|
218
|
|
219
|
--
|
220
|
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
|
221
|
--
|
222
|
|
223
|
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
|
224
|
LANGUAGE plpgsql
|
225
|
AS $$
|
226
|
DECLARE
|
227
|
"Specific_epithet_is_plant" boolean :=
|
228
|
(CASE
|
229
|
WHEN new."Infraspecific_epithet_matched" IS NOT NULL
|
230
|
OR new."Infraspecific_epithet_2_matched" IS NOT NULL
|
231
|
OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
|
232
|
THEN true
|
233
|
ELSE NULL -- ambiguous
|
234
|
END);
|
235
|
never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
|
236
|
-- author disambiguates
|
237
|
family_is_homonym boolean = NOT never_homonym
|
238
|
AND "TNRS".family_is_homonym(new."Family_matched");
|
239
|
genus_is_homonym boolean = NOT never_homonym
|
240
|
AND "TNRS".genus_is_homonym(new."Genus_matched");
|
241
|
matched_taxon_name_with_author text = NULLIF(concat_ws(' '
|
242
|
, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
|
243
|
new."Name_matched")
|
244
|
, NULLIF(new."Name_matched", 'No suitable matches found.')
|
245
|
, new."Name_matched_author"
|
246
|
), '');
|
247
|
accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
|
248
|
, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
|
249
|
new."Accepted_name")
|
250
|
, new."Accepted_name"
|
251
|
, new."Accepted_name_author"
|
252
|
), '');
|
253
|
BEGIN
|
254
|
/* exclude homonyms because these are not valid matches (i.e. TNRS provides
|
255
|
a name, but the name is not meaningful because it is not unambiguous). */
|
256
|
new.is_valid_match = new."Taxonomic_status" != 'Invalid'
|
257
|
AND COALESCE(CASE
|
258
|
WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
|
259
|
THEN true
|
260
|
ELSE -- consider genus
|
261
|
(CASE
|
262
|
WHEN new."Genus_score" = 1 -- exact match
|
263
|
THEN
|
264
|
(CASE
|
265
|
WHEN NOT genus_is_homonym THEN true
|
266
|
ELSE "Specific_epithet_is_plant"
|
267
|
END)
|
268
|
WHEN new."Genus_score" >= 0.85 -- fuzzy match
|
269
|
THEN "Specific_epithet_is_plant"
|
270
|
ELSE NULL -- ambiguous
|
271
|
END)
|
272
|
END, false);
|
273
|
new.scrubbed_unique_taxon_name = COALESCE(
|
274
|
accepted_taxon_name_with_author, matched_taxon_name_with_author);
|
275
|
|
276
|
RETURN new;
|
277
|
END;
|
278
|
$$;
|
279
|
|
280
|
|
281
|
--
|
282
|
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
|
283
|
--
|
284
|
|
285
|
COMMENT ON FUNCTION tnrs_populate_fields() IS '
|
286
|
IMPORTANT: when changing this function, you must regenerate the derived cols:
|
287
|
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
|
288
|
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
|
289
|
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
|
290
|
runtime: 1.5 min ("92633 ms")
|
291
|
';
|
292
|
|
293
|
|
294
|
--
|
295
|
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
|
296
|
--
|
297
|
|
298
|
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
|
299
|
LANGUAGE sql IMMUTABLE
|
300
|
AS $$
|
301
|
SELECT ARRAY[
|
302
|
'Lamiaceae Agastache pallidiflora (Heller) Rydb. spp. pallidiflora var. gilensis R.W. Sanders'
|
303
|
]
|
304
|
$$;
|
305
|
|
306
|
|
307
|
SET default_tablespace = '';
|
308
|
|
309
|
SET default_with_oids = false;
|
310
|
|
311
|
--
|
312
|
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
313
|
--
|
314
|
|
315
|
CREATE TABLE tnrs (
|
316
|
batch text DEFAULT now() NOT NULL,
|
317
|
match_num integer NOT NULL,
|
318
|
"Name_number" integer NOT NULL,
|
319
|
"Name_submitted" text NOT NULL,
|
320
|
"Overall_score" double precision,
|
321
|
"Name_matched" text,
|
322
|
"Name_matched_rank" text,
|
323
|
"Name_score" double precision,
|
324
|
"Name_matched_author" text,
|
325
|
"Name_matched_url" text,
|
326
|
"Author_matched" text,
|
327
|
"Author_score" double precision,
|
328
|
"Family_matched" text,
|
329
|
"Family_score" double precision,
|
330
|
"Name_matched_accepted_family" text,
|
331
|
"Genus_matched" text,
|
332
|
"Genus_score" double precision,
|
333
|
"Specific_epithet_matched" text,
|
334
|
"Specific_epithet_score" double precision,
|
335
|
"Infraspecific_rank" text,
|
336
|
"Infraspecific_epithet_matched" text,
|
337
|
"Infraspecific_epithet_score" double precision,
|
338
|
"Infraspecific_rank_2" text,
|
339
|
"Infraspecific_epithet_2_matched" text,
|
340
|
"Infraspecific_epithet_2_score" double precision,
|
341
|
"Annotations" text,
|
342
|
"Unmatched_terms" text,
|
343
|
"Taxonomic_status" text,
|
344
|
"Accepted_name" text,
|
345
|
"Accepted_name_author" text,
|
346
|
"Accepted_name_rank" text,
|
347
|
"Accepted_name_url" text,
|
348
|
"Accepted_name_species" text,
|
349
|
"Accepted_name_family" text,
|
350
|
"Selected" text,
|
351
|
"Source" text,
|
352
|
"Warnings" text,
|
353
|
"Accepted_name_lsid" text,
|
354
|
is_valid_match boolean NOT NULL,
|
355
|
scrubbed_unique_taxon_name text
|
356
|
);
|
357
|
|
358
|
|
359
|
--
|
360
|
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
|
361
|
--
|
362
|
|
363
|
COMMENT ON TABLE tnrs IS '
|
364
|
to remove columns or add columns at the end:
|
365
|
$ rm=1 inputs/.TNRS/data.sql.run
|
366
|
$ make schemas/remake
|
367
|
|
368
|
to add columns in the middle:
|
369
|
make the changes in inputs/.TNRS/schema.sql
|
370
|
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
|
371
|
$ make schemas/remake
|
372
|
|
373
|
to populate a new column:
|
374
|
ALTER TABLE "TNRS".tnrs DISABLE TRIGGER tnrs_populate_fields; --speeds up update
|
375
|
UPDATE "TNRS".tnrs SET "col" = value;
|
376
|
-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
|
377
|
ALTER TABLE "TNRS".tnrs ENABLE TRIGGER tnrs_populate_fields;
|
378
|
VACUUM ANALYZE "TNRS".tnrs --remove previous rows; runtime: 1.5 min ("92633 ms")
|
379
|
|
380
|
to add a constraint: runtime: 3 min ("173620 ms")
|
381
|
';
|
382
|
|
383
|
|
384
|
--
|
385
|
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
|
386
|
--
|
387
|
|
388
|
CREATE VIEW "MatchedTaxon" AS
|
389
|
SELECT s."*Name_matched.batch",
|
390
|
s."concatenatedScientificName",
|
391
|
s."matchedTaxonName",
|
392
|
s."matchedTaxonRank",
|
393
|
s."*Name_matched.Name_score",
|
394
|
s."matchedScientificNameAuthorship",
|
395
|
s."matchedScientificNameID",
|
396
|
s."*Name_matched.Author_score",
|
397
|
s."matchedFamilyConfidence_fraction",
|
398
|
s."matchedFamily",
|
399
|
s."matchedGenus",
|
400
|
s."matchedGenusConfidence_fraction",
|
401
|
s."matchedSpecificEpithet",
|
402
|
s."matchedSpeciesConfidence_fraction",
|
403
|
s."matchedInfraspecificEpithet",
|
404
|
s."*Name_matched.Infraspecific_epithet_score",
|
405
|
s."identificationQualifier",
|
406
|
s."morphospeciesSuffix",
|
407
|
s."taxonomicStatus",
|
408
|
s.accepted_taxon_name_no_author,
|
409
|
s.accepted_author,
|
410
|
s.accepted_taxon_rank,
|
411
|
s."acceptedScientificNameID",
|
412
|
s.accepted_species_binomial,
|
413
|
s.accepted_family,
|
414
|
s."*Name_matched.Selected",
|
415
|
s."*Name_matched.Source",
|
416
|
s."*Name_matched.Warnings",
|
417
|
s."*Name_matched.Accepted_name_lsid",
|
418
|
s.taxon_scrub__is_valid_match,
|
419
|
s.scrubbed_unique_taxon_name,
|
420
|
CASE
|
421
|
WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
|
422
|
WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
|
423
|
ELSE s.accepted_species_binomial
|
424
|
END AS accepted_morphospecies_binomial
|
425
|
FROM ( SELECT tnrs.batch AS "*Name_matched.batch",
|
426
|
tnrs."Name_submitted" AS "concatenatedScientificName",
|
427
|
tnrs."Name_matched" AS "matchedTaxonName",
|
428
|
tnrs."Name_matched_rank" AS "matchedTaxonRank",
|
429
|
tnrs."Name_score" AS "*Name_matched.Name_score",
|
430
|
tnrs."Name_matched_author" AS "matchedScientificNameAuthorship",
|
431
|
tnrs."Name_matched_url" AS "matchedScientificNameID",
|
432
|
tnrs."Author_score" AS "*Name_matched.Author_score",
|
433
|
tnrs."Family_score" AS "matchedFamilyConfidence_fraction",
|
434
|
COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily",
|
435
|
tnrs."Genus_matched" AS "matchedGenus",
|
436
|
tnrs."Genus_score" AS "matchedGenusConfidence_fraction",
|
437
|
tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet",
|
438
|
tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
|
439
|
tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
|
440
|
tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score",
|
441
|
tnrs."Annotations" AS "identificationQualifier",
|
442
|
tnrs."Unmatched_terms" AS "morphospeciesSuffix",
|
443
|
map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus",
|
444
|
tnrs."Accepted_name" AS accepted_taxon_name_no_author,
|
445
|
tnrs."Accepted_name_author" AS accepted_author,
|
446
|
tnrs."Accepted_name_rank" AS accepted_taxon_rank,
|
447
|
tnrs."Accepted_name_url" AS "acceptedScientificNameID",
|
448
|
tnrs."Accepted_name_species" AS accepted_species_binomial,
|
449
|
tnrs."Accepted_name_family" AS accepted_family,
|
450
|
tnrs."Selected" AS "*Name_matched.Selected",
|
451
|
tnrs."Source" AS "*Name_matched.Source",
|
452
|
tnrs."Warnings" AS "*Name_matched.Warnings",
|
453
|
tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid",
|
454
|
tnrs.is_valid_match AS taxon_scrub__is_valid_match,
|
455
|
tnrs.scrubbed_unique_taxon_name
|
456
|
FROM tnrs) s;
|
457
|
|
458
|
|
459
|
--
|
460
|
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
|
461
|
--
|
462
|
|
463
|
COMMENT ON VIEW "MatchedTaxon" IS '
|
464
|
to modify:
|
465
|
SELECT "TNRS"."MatchedTaxon_modify"($$
|
466
|
SELECT *, __ AS accepted_morphospecies_binomial
|
467
|
FROM __
|
468
|
$$);
|
469
|
';
|
470
|
|
471
|
|
472
|
--
|
473
|
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
|
474
|
--
|
475
|
|
476
|
CREATE VIEW "ValidMatchedTaxon" AS
|
477
|
SELECT "MatchedTaxon"."*Name_matched.batch",
|
478
|
"MatchedTaxon"."concatenatedScientificName",
|
479
|
"MatchedTaxon"."matchedTaxonName",
|
480
|
"MatchedTaxon"."matchedTaxonRank",
|
481
|
"MatchedTaxon"."*Name_matched.Name_score",
|
482
|
"MatchedTaxon"."matchedScientificNameAuthorship",
|
483
|
"MatchedTaxon"."matchedScientificNameID",
|
484
|
"MatchedTaxon"."*Name_matched.Author_score",
|
485
|
"MatchedTaxon"."matchedFamilyConfidence_fraction",
|
486
|
"MatchedTaxon"."matchedFamily",
|
487
|
"MatchedTaxon"."matchedGenus",
|
488
|
"MatchedTaxon"."matchedGenusConfidence_fraction",
|
489
|
"MatchedTaxon"."matchedSpecificEpithet",
|
490
|
"MatchedTaxon"."matchedSpeciesConfidence_fraction",
|
491
|
"MatchedTaxon"."matchedInfraspecificEpithet",
|
492
|
"MatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
|
493
|
"MatchedTaxon"."identificationQualifier",
|
494
|
"MatchedTaxon"."morphospeciesSuffix",
|
495
|
"MatchedTaxon"."taxonomicStatus",
|
496
|
"MatchedTaxon".accepted_taxon_name_no_author,
|
497
|
"MatchedTaxon".accepted_author,
|
498
|
"MatchedTaxon".accepted_taxon_rank,
|
499
|
"MatchedTaxon"."acceptedScientificNameID",
|
500
|
"MatchedTaxon".accepted_species_binomial,
|
501
|
"MatchedTaxon".accepted_family,
|
502
|
"MatchedTaxon"."*Name_matched.Selected",
|
503
|
"MatchedTaxon"."*Name_matched.Source",
|
504
|
"MatchedTaxon"."*Name_matched.Warnings",
|
505
|
"MatchedTaxon"."*Name_matched.Accepted_name_lsid",
|
506
|
"MatchedTaxon".taxon_scrub__is_valid_match,
|
507
|
"MatchedTaxon".scrubbed_unique_taxon_name,
|
508
|
"MatchedTaxon".accepted_morphospecies_binomial
|
509
|
FROM "MatchedTaxon"
|
510
|
WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
|
511
|
|
512
|
|
513
|
--
|
514
|
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
|
515
|
--
|
516
|
|
517
|
COMMENT ON VIEW "ValidMatchedTaxon" IS '
|
518
|
to update, use * as the column list
|
519
|
';
|
520
|
|
521
|
|
522
|
--
|
523
|
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
524
|
--
|
525
|
|
526
|
CREATE TABLE batch (
|
527
|
id text NOT NULL,
|
528
|
id_by_time text,
|
529
|
time_submitted timestamp with time zone DEFAULT now(),
|
530
|
client_version text
|
531
|
);
|
532
|
|
533
|
|
534
|
--
|
535
|
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
536
|
--
|
537
|
|
538
|
CREATE TABLE batch_download_settings (
|
539
|
id text NOT NULL,
|
540
|
"E-mail" text,
|
541
|
"Id" text,
|
542
|
"Job type" text,
|
543
|
"Contains Id" boolean,
|
544
|
"Start time" text,
|
545
|
"Finish time" text,
|
546
|
"TNRS version" text,
|
547
|
"Sources selected" text,
|
548
|
"Match threshold" double precision,
|
549
|
"Classification" text,
|
550
|
"Allow partial matches?" boolean,
|
551
|
"Sort by source" boolean,
|
552
|
"Constrain by higher taxonomy" boolean
|
553
|
);
|
554
|
|
555
|
|
556
|
--
|
557
|
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
|
558
|
--
|
559
|
|
560
|
COMMENT ON TABLE batch_download_settings IS '
|
561
|
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
|
562
|
';
|
563
|
|
564
|
|
565
|
--
|
566
|
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
567
|
--
|
568
|
|
569
|
CREATE TABLE client_version (
|
570
|
id text NOT NULL,
|
571
|
global_rev integer NOT NULL,
|
572
|
"/lib/tnrs.py rev" integer,
|
573
|
"/bin/tnrs_db rev" integer
|
574
|
);
|
575
|
|
576
|
|
577
|
--
|
578
|
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
|
579
|
--
|
580
|
|
581
|
COMMENT ON TABLE client_version IS '
|
582
|
contains svn revisions
|
583
|
';
|
584
|
|
585
|
|
586
|
--
|
587
|
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
|
588
|
--
|
589
|
|
590
|
COMMENT ON COLUMN client_version.global_rev IS '
|
591
|
from `svn info .` > Last Changed Rev
|
592
|
';
|
593
|
|
594
|
|
595
|
--
|
596
|
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
597
|
--
|
598
|
|
599
|
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
|
600
|
from `svn info lib/tnrs.py` > Last Changed Rev
|
601
|
';
|
602
|
|
603
|
|
604
|
--
|
605
|
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
606
|
--
|
607
|
|
608
|
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
|
609
|
from `svn info bin/tnrs_db` > Last Changed Rev
|
610
|
';
|
611
|
|
612
|
|
613
|
--
|
614
|
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
|
615
|
--
|
616
|
|
617
|
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
|
618
|
SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name,
|
619
|
tnrs."Name_matched_rank" AS scrubbed_taxon_rank,
|
620
|
COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family,
|
621
|
tnrs."Genus_matched" AS scrubbed_genus,
|
622
|
tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet,
|
623
|
tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank,
|
624
|
tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
|
625
|
tnrs."Name_matched_author" AS scrubbed_author,
|
626
|
tnrs."Name_matched" AS scrubbed_taxon_name_no_author,
|
627
|
(tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
|
628
|
FROM tnrs;
|
629
|
|
630
|
|
631
|
--
|
632
|
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
|
633
|
--
|
634
|
|
635
|
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
|
636
|
scrubbed_family: Name_matched_accepted_family was missing from the TNRS results at one point, so Family_matched is used as a workaround to populate this. the workaround is for *accepted names only*, as no opinion names do not have an Accepted_name_family to prepend to the scrubbed name to parse.
|
637
|
';
|
638
|
|
639
|
|
640
|
--
|
641
|
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
|
642
|
--
|
643
|
|
644
|
CREATE VIEW taxon_scrub AS
|
645
|
SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
|
646
|
"ValidMatchedTaxon"."*Name_matched.batch",
|
647
|
"ValidMatchedTaxon"."concatenatedScientificName",
|
648
|
"ValidMatchedTaxon"."matchedTaxonName",
|
649
|
"ValidMatchedTaxon"."matchedTaxonRank",
|
650
|
"ValidMatchedTaxon"."*Name_matched.Name_score",
|
651
|
"ValidMatchedTaxon"."matchedScientificNameAuthorship",
|
652
|
"ValidMatchedTaxon"."matchedScientificNameID",
|
653
|
"ValidMatchedTaxon"."*Name_matched.Author_score",
|
654
|
"ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
|
655
|
"ValidMatchedTaxon"."matchedFamily",
|
656
|
"ValidMatchedTaxon"."matchedGenus",
|
657
|
"ValidMatchedTaxon"."matchedGenusConfidence_fraction",
|
658
|
"ValidMatchedTaxon"."matchedSpecificEpithet",
|
659
|
"ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
|
660
|
"ValidMatchedTaxon"."matchedInfraspecificEpithet",
|
661
|
"ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
|
662
|
"ValidMatchedTaxon"."identificationQualifier",
|
663
|
"ValidMatchedTaxon"."morphospeciesSuffix",
|
664
|
"ValidMatchedTaxon"."taxonomicStatus",
|
665
|
"ValidMatchedTaxon".accepted_taxon_name_no_author,
|
666
|
"ValidMatchedTaxon".accepted_author,
|
667
|
"ValidMatchedTaxon".accepted_taxon_rank,
|
668
|
"ValidMatchedTaxon"."acceptedScientificNameID",
|
669
|
"ValidMatchedTaxon".accepted_species_binomial,
|
670
|
"ValidMatchedTaxon".accepted_family,
|
671
|
"ValidMatchedTaxon"."*Name_matched.Selected",
|
672
|
"ValidMatchedTaxon"."*Name_matched.Source",
|
673
|
"ValidMatchedTaxon"."*Name_matched.Warnings",
|
674
|
"ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid",
|
675
|
"ValidMatchedTaxon".taxon_scrub__is_valid_match,
|
676
|
"ValidMatchedTaxon".accepted_morphospecies_binomial,
|
677
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
|
678
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
|
679
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
|
680
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
|
681
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
|
682
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
|
683
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
|
684
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
|
685
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
|
686
|
CASE
|
687
|
WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'family'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "ValidMatchedTaxon"."morphospeciesSuffix")
|
688
|
WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, "ValidMatchedTaxon"."morphospeciesSuffix")
|
689
|
ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
|
690
|
END AS scrubbed_morphospecies_binomial
|
691
|
FROM ("ValidMatchedTaxon"
|
692
|
LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
|
693
|
|
694
|
|
695
|
--
|
696
|
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
|
697
|
--
|
698
|
|
699
|
COMMENT ON VIEW taxon_scrub IS '
|
700
|
to modify:
|
701
|
SELECT "TNRS".taxon_scrub_modify($$
|
702
|
SELECT *, __ AS scrubbed_morphospecies_binomial
|
703
|
FROM "TNRS"."ValidMatchedTaxon"
|
704
|
LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
|
705
|
$$);
|
706
|
';
|
707
|
|
708
|
|
709
|
--
|
710
|
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
711
|
--
|
712
|
|
713
|
ALTER TABLE ONLY batch_download_settings
|
714
|
ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
|
715
|
|
716
|
|
717
|
--
|
718
|
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
719
|
--
|
720
|
|
721
|
ALTER TABLE ONLY batch
|
722
|
ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
|
723
|
|
724
|
|
725
|
--
|
726
|
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
727
|
--
|
728
|
|
729
|
ALTER TABLE ONLY batch
|
730
|
ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
|
731
|
|
732
|
|
733
|
--
|
734
|
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
735
|
--
|
736
|
|
737
|
ALTER TABLE ONLY client_version
|
738
|
ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
|
739
|
|
740
|
|
741
|
--
|
742
|
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
743
|
--
|
744
|
|
745
|
ALTER TABLE ONLY tnrs
|
746
|
ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, match_num);
|
747
|
|
748
|
|
749
|
--
|
750
|
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
751
|
--
|
752
|
|
753
|
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
|
754
|
|
755
|
|
756
|
--
|
757
|
-- Name: tnrs_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
758
|
--
|
759
|
|
760
|
CREATE INDEX "tnrs_Name_submitted_idx" ON tnrs USING btree ("Name_submitted");
|
761
|
|
762
|
|
763
|
--
|
764
|
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
765
|
--
|
766
|
|
767
|
CREATE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
|
768
|
|
769
|
|
770
|
--
|
771
|
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
772
|
--
|
773
|
|
774
|
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
|
775
|
|
776
|
|
777
|
--
|
778
|
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
|
779
|
--
|
780
|
|
781
|
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
|
782
|
|
783
|
|
784
|
--
|
785
|
-- Name: tnrs__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
786
|
--
|
787
|
|
788
|
CREATE TRIGGER tnrs__match_num__fill BEFORE INSERT ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs__match_num__fill();
|
789
|
|
790
|
|
791
|
--
|
792
|
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
|
793
|
--
|
794
|
|
795
|
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
|
796
|
|
797
|
|
798
|
--
|
799
|
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
800
|
--
|
801
|
|
802
|
ALTER TABLE ONLY batch
|
803
|
ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
804
|
|
805
|
|
806
|
--
|
807
|
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
808
|
--
|
809
|
|
810
|
ALTER TABLE ONLY batch_download_settings
|
811
|
ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
812
|
|
813
|
|
814
|
--
|
815
|
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
816
|
--
|
817
|
|
818
|
ALTER TABLE ONLY tnrs
|
819
|
ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
820
|
|
821
|
|
822
|
--
|
823
|
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
|
824
|
--
|
825
|
|
826
|
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
|
827
|
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
|
828
|
GRANT ALL ON SCHEMA "TNRS" TO bien;
|
829
|
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
|
830
|
|
831
|
|
832
|
--
|
833
|
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
|
834
|
--
|
835
|
|
836
|
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
|
837
|
REVOKE ALL ON TABLE tnrs FROM bien;
|
838
|
GRANT ALL ON TABLE tnrs TO bien;
|
839
|
GRANT SELECT ON TABLE tnrs TO bien_read;
|
840
|
|
841
|
|
842
|
--
|
843
|
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
|
844
|
--
|
845
|
|
846
|
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
|
847
|
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
|
848
|
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
|
849
|
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
|
850
|
|
851
|
|
852
|
--
|
853
|
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
|
854
|
--
|
855
|
|
856
|
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
|
857
|
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
|
858
|
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
|
859
|
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
|
860
|
|
861
|
|
862
|
--
|
863
|
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
|
864
|
--
|
865
|
|
866
|
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
|
867
|
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
|
868
|
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
|
869
|
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
|
870
|
|
871
|
|
872
|
--
|
873
|
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
|
874
|
--
|
875
|
|
876
|
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
|
877
|
REVOKE ALL ON TABLE taxon_scrub FROM bien;
|
878
|
GRANT ALL ON TABLE taxon_scrub TO bien;
|
879
|
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
|
880
|
|
881
|
|
882
|
--
|
883
|
-- PostgreSQL database dump complete
|
884
|
--
|
885
|
|