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 13570 aaronmk
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
178
--
179
180
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
181
    LANGUAGE sql
182
    AS $$
183
SELECT nextval('pg_temp.tnrs__match_num__seq');
184
$$;
185
186
187
--
188 10778 aaronmk
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
189
--
190
191
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
192
    LANGUAGE plpgsql
193
    AS $$
194 9763 aaronmk
DECLARE
195 11628 aaronmk
	"Specific_epithet_is_plant" boolean :=
196
		(CASE
197
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
198
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
199
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
200
			THEN true
201
		ELSE NULL -- ambiguous
202
		END);
203
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
204
		-- author disambiguates
205
	family_is_homonym boolean = NOT never_homonym
206
		AND "TNRS".family_is_homonym(new."Family_matched");
207
	genus_is_homonym  boolean = NOT never_homonym
208
		AND "TNRS".genus_is_homonym(new."Genus_matched");
209
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
210
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
211
			new."Name_matched")
212
		, NULLIF(new."Name_matched", 'No suitable matches found.')
213
		, new."Name_matched_author"
214
		), '');
215 11643 aaronmk
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
216 11628 aaronmk
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
217
			new."Accepted_name")
218
		, new."Accepted_name"
219
		, new."Accepted_name_author"
220
		), '');
221 11643 aaronmk
BEGIN
222 11629 aaronmk
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
223
	a name, but the name is not meaningful because it is not unambiguous). */
224 11711 aaronmk
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
225
		AND COALESCE(CASE
226 11628 aaronmk
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
227
			THEN true
228
		ELSE -- consider genus
229
			(CASE
230
			WHEN new."Genus_score" =  1	   -- exact match
231
				THEN
232
				(CASE
233
				WHEN NOT genus_is_homonym THEN true
234
				ELSE "Specific_epithet_is_plant"
235
				END)
236
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
237
				THEN "Specific_epithet_is_plant"
238
			ELSE NULL -- ambiguous
239
			END)
240 11629 aaronmk
		END, false);
241 11632 aaronmk
	new.scrubbed_unique_taxon_name = COALESCE(
242 11643 aaronmk
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
243 11628 aaronmk
244
	RETURN new;
245 7134 aaronmk
END;
246 10778 aaronmk
$$;
247
248
249
--
250
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
251
--
252
253 13575 aaronmk
COMMENT ON FUNCTION tnrs_populate_fields() IS '
254
IMPORTANT: when changing this function, you must regenerate the derived cols:
255 10754 aaronmk
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
256 11715 aaronmk
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
257 10754 aaronmk
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
258 13575 aaronmk
runtime: 1.5 min ("92633 ms")
259
';
260 7134 aaronmk
261 7251 aaronmk
262 10778 aaronmk
SET default_tablespace = '';
263
264
SET default_with_oids = false;
265
266 10728 aaronmk
--
267 10778 aaronmk
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
268
--
269 7251 aaronmk
270 10778 aaronmk
CREATE TABLE tnrs (
271
    batch text DEFAULT now() NOT NULL,
272 13573 aaronmk
    match_num integer,
273 10778 aaronmk
    "Name_number" integer NOT NULL,
274
    "Name_submitted" text NOT NULL,
275
    "Overall_score" double precision,
276
    "Name_matched" text,
277
    "Name_matched_rank" text,
278
    "Name_score" double precision,
279
    "Name_matched_author" text,
280
    "Name_matched_url" text,
281
    "Author_matched" text,
282
    "Author_score" double precision,
283
    "Family_matched" text,
284
    "Family_score" double precision,
285
    "Name_matched_accepted_family" text,
286
    "Genus_matched" text,
287
    "Genus_score" double precision,
288
    "Specific_epithet_matched" text,
289
    "Specific_epithet_score" double precision,
290
    "Infraspecific_rank" text,
291
    "Infraspecific_epithet_matched" text,
292
    "Infraspecific_epithet_score" double precision,
293
    "Infraspecific_rank_2" text,
294
    "Infraspecific_epithet_2_matched" text,
295
    "Infraspecific_epithet_2_score" double precision,
296
    "Annotations" text,
297
    "Unmatched_terms" text,
298
    "Taxonomic_status" text,
299
    "Accepted_name" text,
300
    "Accepted_name_author" text,
301
    "Accepted_name_rank" text,
302
    "Accepted_name_url" text,
303
    "Accepted_name_species" text,
304
    "Accepted_name_family" text,
305
    "Selected" text,
306
    "Source" text,
307
    "Warnings" text,
308
    "Accepted_name_lsid" text,
309 11628 aaronmk
    is_valid_match boolean NOT NULL,
310 11632 aaronmk
    scrubbed_unique_taxon_name text
311 10778 aaronmk
);
312 7823 aaronmk
313 9759 aaronmk
314 10778 aaronmk
--
315
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
316
--
317 7823 aaronmk
318 13575 aaronmk
COMMENT ON TABLE tnrs IS '
319
IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
320
$ inputs/.TNRS/data.sql.run refresh
321
';
322 10778 aaronmk
323
324
--
325
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
326
--
327
328
CREATE VIEW "MatchedTaxon" AS
329 13498 aaronmk
 SELECT s."*Name_matched.batch",
330
    s."concatenatedScientificName",
331
    s."matchedTaxonName",
332
    s."matchedTaxonRank",
333
    s."*Name_matched.Name_score",
334
    s."matchedScientificNameAuthorship",
335
    s."matchedScientificNameID",
336
    s."*Name_matched.Author_score",
337
    s."matchedFamilyConfidence_fraction",
338
    s."matchedFamily",
339
    s."matchedGenus",
340
    s."matchedGenusConfidence_fraction",
341
    s."matchedSpecificEpithet",
342
    s."matchedSpeciesConfidence_fraction",
343
    s."matchedInfraspecificEpithet",
344
    s."*Name_matched.Infraspecific_epithet_score",
345
    s."identificationQualifier",
346
    s."morphospeciesSuffix",
347
    s."taxonomicStatus",
348
    s.accepted_taxon_name_no_author,
349
    s.accepted_author,
350
    s.accepted_taxon_rank,
351
    s."acceptedScientificNameID",
352
    s.accepted_species_binomial,
353
    s.accepted_family,
354
    s."*Name_matched.Selected",
355
    s."*Name_matched.Source",
356
    s."*Name_matched.Warnings",
357
    s."*Name_matched.Accepted_name_lsid",
358
    s.taxon_scrub__is_valid_match,
359
    s.scrubbed_unique_taxon_name,
360
        CASE
361
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
362
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
363
            ELSE s.accepted_species_binomial
364
        END AS accepted_morphospecies_binomial
365
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch",
366
            tnrs."Name_submitted" AS "concatenatedScientificName",
367
            tnrs."Name_matched" AS "matchedTaxonName",
368
            tnrs."Name_matched_rank" AS "matchedTaxonRank",
369
            tnrs."Name_score" AS "*Name_matched.Name_score",
370
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship",
371
            tnrs."Name_matched_url" AS "matchedScientificNameID",
372
            tnrs."Author_score" AS "*Name_matched.Author_score",
373
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction",
374
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily",
375
            tnrs."Genus_matched" AS "matchedGenus",
376
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction",
377
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet",
378
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
379
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
380
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score",
381
            tnrs."Annotations" AS "identificationQualifier",
382
            tnrs."Unmatched_terms" AS "morphospeciesSuffix",
383 13508 aaronmk
            map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus",
384 13498 aaronmk
            tnrs."Accepted_name" AS accepted_taxon_name_no_author,
385
            tnrs."Accepted_name_author" AS accepted_author,
386
            tnrs."Accepted_name_rank" AS accepted_taxon_rank,
387
            tnrs."Accepted_name_url" AS "acceptedScientificNameID",
388
            tnrs."Accepted_name_species" AS accepted_species_binomial,
389
            tnrs."Accepted_name_family" AS accepted_family,
390
            tnrs."Selected" AS "*Name_matched.Selected",
391
            tnrs."Source" AS "*Name_matched.Source",
392
            tnrs."Warnings" AS "*Name_matched.Warnings",
393
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid",
394
            tnrs.is_valid_match AS taxon_scrub__is_valid_match,
395
            tnrs.scrubbed_unique_taxon_name
396
           FROM tnrs) s;
397 10778 aaronmk
398
399
--
400 13498 aaronmk
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
401
--
402
403
COMMENT ON VIEW "MatchedTaxon" IS '
404 13501 aaronmk
to modify:
405 13507 aaronmk
SELECT "TNRS"."MatchedTaxon_modify"($$
406
 SELECT *, __ AS accepted_morphospecies_binomial
407
   FROM __
408 13501 aaronmk
$$);
409 13498 aaronmk
';
410
411
412
--
413 10778 aaronmk
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
414
--
415
416
CREATE VIEW "ValidMatchedTaxon" AS
417 11708 aaronmk
 SELECT "MatchedTaxon"."*Name_matched.batch",
418
    "MatchedTaxon"."concatenatedScientificName",
419
    "MatchedTaxon"."matchedTaxonName",
420
    "MatchedTaxon"."matchedTaxonRank",
421
    "MatchedTaxon"."*Name_matched.Name_score",
422
    "MatchedTaxon"."matchedScientificNameAuthorship",
423
    "MatchedTaxon"."matchedScientificNameID",
424
    "MatchedTaxon"."*Name_matched.Author_score",
425
    "MatchedTaxon"."matchedFamilyConfidence_fraction",
426
    "MatchedTaxon"."matchedFamily",
427
    "MatchedTaxon"."matchedGenus",
428
    "MatchedTaxon"."matchedGenusConfidence_fraction",
429
    "MatchedTaxon"."matchedSpecificEpithet",
430
    "MatchedTaxon"."matchedSpeciesConfidence_fraction",
431
    "MatchedTaxon"."matchedInfraspecificEpithet",
432
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
433
    "MatchedTaxon"."identificationQualifier",
434
    "MatchedTaxon"."morphospeciesSuffix",
435
    "MatchedTaxon"."taxonomicStatus",
436 13441 aaronmk
    "MatchedTaxon".accepted_taxon_name_no_author,
437
    "MatchedTaxon".accepted_author,
438
    "MatchedTaxon".accepted_taxon_rank,
439 11708 aaronmk
    "MatchedTaxon"."acceptedScientificNameID",
440 13444 aaronmk
    "MatchedTaxon".accepted_species_binomial,
441 13441 aaronmk
    "MatchedTaxon".accepted_family,
442 11708 aaronmk
    "MatchedTaxon"."*Name_matched.Selected",
443
    "MatchedTaxon"."*Name_matched.Source",
444
    "MatchedTaxon"."*Name_matched.Warnings",
445
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid",
446
    "MatchedTaxon".taxon_scrub__is_valid_match,
447 13498 aaronmk
    "MatchedTaxon".scrubbed_unique_taxon_name,
448
    "MatchedTaxon".accepted_morphospecies_binomial
449 11708 aaronmk
   FROM "MatchedTaxon"
450
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
451 10778 aaronmk
452
453
--
454
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
455
--
456
457 13443 aaronmk
COMMENT ON VIEW "ValidMatchedTaxon" IS '
458
to update, use * as the column list
459
';
460 10778 aaronmk
461
462
--
463
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
464
--
465
466
CREATE TABLE batch (
467
    id text NOT NULL,
468
    id_by_time text,
469
    time_submitted timestamp with time zone DEFAULT now(),
470
    client_version text
471
);
472
473
474
--
475
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
476
--
477
478
CREATE TABLE batch_download_settings (
479
    id text NOT NULL,
480
    "E-mail" text,
481
    "Id" text,
482
    "Job type" text,
483
    "Contains Id" boolean,
484
    "Start time" text,
485
    "Finish time" text,
486
    "TNRS version" text,
487
    "Sources selected" text,
488
    "Match threshold" double precision,
489
    "Classification" text,
490
    "Allow partial matches?" boolean,
491
    "Sort by source" boolean,
492
    "Constrain by higher taxonomy" boolean
493
);
494
495
496
--
497
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
498
--
499
500 13575 aaronmk
COMMENT ON TABLE batch_download_settings IS '
501
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
502
';
503 10778 aaronmk
504
505
--
506
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
507
--
508
509
CREATE TABLE client_version (
510
    id text NOT NULL,
511
    global_rev integer NOT NULL,
512
    "/lib/tnrs.py rev" integer,
513
    "/bin/tnrs_db rev" integer
514
);
515
516
517
--
518
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
519
--
520
521 13575 aaronmk
COMMENT ON TABLE client_version IS '
522
contains svn revisions
523
';
524 10778 aaronmk
525
526
--
527
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
528
--
529
530 13575 aaronmk
COMMENT ON COLUMN client_version.global_rev IS '
531
from `svn info .` > Last Changed Rev
532
';
533 10778 aaronmk
534
535
--
536
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
537
--
538
539 13575 aaronmk
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
540
from `svn info lib/tnrs.py` > Last Changed Rev
541
';
542 10778 aaronmk
543
544
--
545
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
546
--
547
548 13575 aaronmk
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
549
from `svn info bin/tnrs_db` > Last Changed Rev
550
';
551 10778 aaronmk
552
553
--
554 11964 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
555
--
556
557
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
558
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name,
559 13441 aaronmk
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank,
560
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family,
561 11964 aaronmk
    tnrs."Genus_matched" AS scrubbed_genus,
562
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet,
563
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank,
564
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
565 13441 aaronmk
    tnrs."Name_matched_author" AS scrubbed_author,
566 13540 aaronmk
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author,
567
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
568 11964 aaronmk
   FROM tnrs;
569
570
571
--
572 11965 aaronmk
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
573
--
574
575 13575 aaronmk
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
576
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.
577
';
578 11965 aaronmk
579
580
--
581 11964 aaronmk
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
582
--
583
584
CREATE VIEW taxon_scrub AS
585
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
586
    "ValidMatchedTaxon"."*Name_matched.batch",
587
    "ValidMatchedTaxon"."concatenatedScientificName",
588
    "ValidMatchedTaxon"."matchedTaxonName",
589
    "ValidMatchedTaxon"."matchedTaxonRank",
590
    "ValidMatchedTaxon"."*Name_matched.Name_score",
591
    "ValidMatchedTaxon"."matchedScientificNameAuthorship",
592
    "ValidMatchedTaxon"."matchedScientificNameID",
593
    "ValidMatchedTaxon"."*Name_matched.Author_score",
594
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
595
    "ValidMatchedTaxon"."matchedFamily",
596
    "ValidMatchedTaxon"."matchedGenus",
597
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction",
598
    "ValidMatchedTaxon"."matchedSpecificEpithet",
599
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
600
    "ValidMatchedTaxon"."matchedInfraspecificEpithet",
601
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
602
    "ValidMatchedTaxon"."identificationQualifier",
603
    "ValidMatchedTaxon"."morphospeciesSuffix",
604
    "ValidMatchedTaxon"."taxonomicStatus",
605 13441 aaronmk
    "ValidMatchedTaxon".accepted_taxon_name_no_author,
606
    "ValidMatchedTaxon".accepted_author,
607
    "ValidMatchedTaxon".accepted_taxon_rank,
608 11964 aaronmk
    "ValidMatchedTaxon"."acceptedScientificNameID",
609 13444 aaronmk
    "ValidMatchedTaxon".accepted_species_binomial,
610 13441 aaronmk
    "ValidMatchedTaxon".accepted_family,
611 11964 aaronmk
    "ValidMatchedTaxon"."*Name_matched.Selected",
612
    "ValidMatchedTaxon"."*Name_matched.Source",
613
    "ValidMatchedTaxon"."*Name_matched.Warnings",
614
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid",
615
    "ValidMatchedTaxon".taxon_scrub__is_valid_match,
616 13498 aaronmk
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
617 13441 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
618
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
619 11964 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
620
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
621
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
622
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
623 13441 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
624 13532 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
625 13540 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
626 13532 aaronmk
        CASE
627
            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")
628
            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")
629
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
630
        END AS scrubbed_morphospecies_binomial
631 11964 aaronmk
   FROM ("ValidMatchedTaxon"
632
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
633
634
635
--
636
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
637
--
638
639 13443 aaronmk
COMMENT ON VIEW taxon_scrub IS '
640 13531 aaronmk
to modify:
641
SELECT "TNRS".taxon_scrub_modify($$
642 13533 aaronmk
 SELECT *, __ AS scrubbed_morphospecies_binomial
643 13531 aaronmk
   FROM "TNRS"."ValidMatchedTaxon"
644
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
645
$$);
646 13443 aaronmk
';
647 11964 aaronmk
648
649
--
650 10778 aaronmk
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
651
--
652
653
ALTER TABLE ONLY batch_download_settings
654
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
655
656
657
--
658
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
659
--
660
661
ALTER TABLE ONLY batch
662
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
663
664
665
--
666
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
667
--
668
669
ALTER TABLE ONLY batch
670
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
671
672
673
--
674
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
675
--
676
677
ALTER TABLE ONLY client_version
678
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
679
680
681
--
682
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
683
--
684
685
ALTER TABLE ONLY tnrs
686
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
687
688
689
--
690
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
691
--
692
693
ALTER TABLE ONLY tnrs
694
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
695
696
697
--
698 10793 aaronmk
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
699
--
700
701
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
702
703
704
--
705 11607 aaronmk
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
706
--
707
708
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
709
710
711
--
712 10778 aaronmk
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
713
--
714
715
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
716
717
718
--
719 13567 aaronmk
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
720
--
721
722
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
723
724
725
--
726 10778 aaronmk
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
727
--
728
729
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
730
731
732
--
733
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
734
--
735
736
ALTER TABLE ONLY batch
737
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
738
739
740
--
741
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
742
--
743
744
ALTER TABLE ONLY batch_download_settings
745
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
746
747
748
--
749
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
750
--
751
752
ALTER TABLE ONLY tnrs
753
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
754
755
756
--
757
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
758
--
759
760
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
761
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
762
GRANT ALL ON SCHEMA "TNRS" TO bien;
763
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
764
765
766
--
767
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
768
--
769
770
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
771
REVOKE ALL ON TABLE tnrs FROM bien;
772
GRANT ALL ON TABLE tnrs TO bien;
773
GRANT SELECT ON TABLE tnrs TO bien_read;
774
775
776
--
777 11912 aaronmk
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
778
--
779
780
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
781
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
782
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
783
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
784
785
786
--
787
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
788
--
789
790
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
791
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
792
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
793
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
794
795
796
--
797
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
798
--
799
800
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
801
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
802
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
803
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
804
805
806
--
807
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
808
--
809
810
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
811
REVOKE ALL ON TABLE taxon_scrub FROM bien;
812
GRANT ALL ON TABLE taxon_scrub TO bien;
813
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
814
815
816
--
817 10778 aaronmk
-- PostgreSQL database dump complete
818
--