Project

General

Profile

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