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