Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
--CREATE SCHEMA "TNRS";
17

    
18

    
19
--
20
-- Name: SCHEMA "TNRS"; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
COMMENT ON SCHEMA "TNRS" IS '
24
IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
25
on vegbiendev:
26
# back up existing TNRS schema (in case of an accidental incorrect change):
27
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
28
$ svn up
29
$ svn di
30
# make the changes shown in the diff
31
## to change column types:
32
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
33
  (''col'', ''new_type'')
34
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
35
$ rm=1 inputs/.TNRS/schema.sql.run
36
# repeat until `svn di` shows no diff
37
# back up new TNRS schema:
38
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
39
';
40

    
41

    
42
SET search_path = "TNRS", pg_catalog;
43

    
44
--
45
-- Name: MatchedTaxon_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47

    
48
CREATE FUNCTION "MatchedTaxon_modify"(view_query text DEFAULT NULL::text) RETURNS void
49
    LANGUAGE sql
50
    AS $_$
51
SELECT util.recreate_view('"TNRS"."MatchedTaxon"', $1);
52
$_$;
53

    
54

    
55
--
56
-- Name: FUNCTION "MatchedTaxon_modify"(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
57
--
58

    
59
COMMENT ON FUNCTION "MatchedTaxon_modify"(view_query text) IS '
60
usage:
61
SELECT "TNRS"."MatchedTaxon_modify"($$
62
SELECT __
63
$$);
64

    
65
idempotent
66
';
67

    
68

    
69
--
70
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
71
--
72

    
73
CREATE FUNCTION batch__fill() RETURNS trigger
74
    LANGUAGE plpgsql
75
    AS $$
76
BEGIN
77
	new.id_by_time = new.time_submitted;
78
	new.id = COALESCE(new.id, new.id_by_time);
79
	RETURN new;
80
END;
81
$$;
82

    
83

    
84
--
85
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
86
--
87

    
88
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
89
    LANGUAGE sql STABLE STRICT
90
    AS $_$
91
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
92
$_$;
93

    
94

    
95
--
96
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
97
--
98

    
99
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
100
    LANGUAGE sql STABLE STRICT
101
    AS $_$
102
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
103
$_$;
104

    
105

    
106
--
107
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
108
--
109

    
110
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
111
    LANGUAGE sql IMMUTABLE
112
    AS $_$
113
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
114
"taxonomic_status should be accepted instead of synonym when an accepted name is
115
available (this is not always the case when a name is marked as a synonym)" */
116
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
117
$_$;
118

    
119

    
120
--
121
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
122
--
123

    
124
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
125
    LANGUAGE sql IMMUTABLE
126
    AS $_$
127
SELECT $1 != ANY("TNRS".unsafe_taxon_names())
128
$_$;
129

    
130

    
131
--
132
-- Name: taxon_scrub_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
133
--
134

    
135
CREATE FUNCTION taxon_scrub_modify(view_query text DEFAULT NULL::text) RETURNS void
136
    LANGUAGE sql
137
    AS $_$
138
SELECT util.recreate_view('"TNRS".taxon_scrub', $1);
139
$_$;
140

    
141

    
142
--
143
-- Name: FUNCTION taxon_scrub_modify(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
144
--
145

    
146
COMMENT ON FUNCTION taxon_scrub_modify(view_query text) IS '
147
usage:
148
SELECT "TNRS".taxon_scrub_modify($$
149
SELECT __
150
$$);
151

    
152
idempotent
153
';
154

    
155

    
156
--
157
-- Name: tnrs__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
158
--
159

    
160
CREATE FUNCTION tnrs__batch_begin() RETURNS trigger
161
    LANGUAGE plpgsql
162
    AS $$
163
BEGIN
164
	PERFORM util.seq__reset('pg_temp.tnrs__match_num__seq', 0);
165
	RETURN NULL;
166
END;
167
$$;
168

    
169

    
170
--
171
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
172
--
173

    
174
CREATE FUNCTION tnrs__match_num__fill() RETURNS trigger
175
    LANGUAGE plpgsql
176
    AS $$
177
BEGIN
178
	IF new.match_num IS NULL THEN
179
		new.match_num = "TNRS".tnrs__match_num__next();
180
	END IF;
181
	RETURN new;
182
END;
183
$$;
184

    
185

    
186
--
187
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
188
--
189

    
190
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
191
    LANGUAGE sql
192
    AS $$
193
SELECT nextval('pg_temp.tnrs__match_num__seq');
194
$$;
195

    
196

    
197
--
198
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
199
--
200

    
201
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
202
    LANGUAGE plpgsql
203
    AS $$
204
DECLARE
205
	"Specific_epithet_is_plant" boolean :=
206
		(CASE
207
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
208
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
209
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
210
			THEN true
211
		ELSE NULL -- ambiguous
212
		END);
213
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
214
		-- author disambiguates
215
	family_is_homonym boolean = NOT never_homonym
216
		AND "TNRS".family_is_homonym(new."Family_matched");
217
	genus_is_homonym  boolean = NOT never_homonym
218
		AND "TNRS".genus_is_homonym(new."Genus_matched");
219
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
220
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
221
			new."Name_matched")
222
		, NULLIF(new."Name_matched", 'No suitable matches found.')
223
		, new."Name_matched_author"
224
		), '');
225
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
226
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
227
			new."Accepted_name")
228
		, new."Accepted_name"
229
		, new."Accepted_name_author"
230
		), '');
231
BEGIN
232
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
233
	a name, but the name is not meaningful because it is not unambiguous). */
234
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
235
		AND COALESCE(CASE
236
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
237
			THEN true
238
		ELSE -- consider genus
239
			(CASE
240
			WHEN new."Genus_score" =  1	   -- exact match
241
				THEN
242
				(CASE
243
				WHEN NOT genus_is_homonym THEN true
244
				ELSE "Specific_epithet_is_plant"
245
				END)
246
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
247
				THEN "Specific_epithet_is_plant"
248
			ELSE NULL -- ambiguous
249
			END)
250
		END, false);
251
	new.scrubbed_unique_taxon_name = COALESCE(
252
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
253
	
254
	RETURN new;
255
END;
256
$$;
257

    
258

    
259
--
260
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
261
--
262

    
263
COMMENT ON FUNCTION tnrs_populate_fields() IS '
264
IMPORTANT: when changing this function, you must regenerate the derived cols:
265
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
266
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
267
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
268
runtime: 1.5 min ("92633 ms")
269
';
270

    
271

    
272
--
273
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
274
--
275

    
276
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
277
    LANGUAGE sql IMMUTABLE
278
    AS $$
279
SELECT ARRAY[
280
'Lamiaceae Agastache pallidiflora (Heller) Rydb. spp. pallidiflora var. gilensis R.W. Sanders'
281
]
282
$$;
283

    
284

    
285
SET default_tablespace = '';
286

    
287
SET default_with_oids = false;
288

    
289
--
290
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
291
--
292

    
293
CREATE TABLE tnrs (
294
    batch text DEFAULT now() NOT NULL,
295
    match_num integer NOT NULL,
296
    "Name_number" integer NOT NULL,
297
    "Name_submitted" text NOT NULL,
298
    "Overall_score" double precision,
299
    "Name_matched" text,
300
    "Name_matched_rank" text,
301
    "Name_score" double precision,
302
    "Name_matched_author" text,
303
    "Name_matched_url" text,
304
    "Author_matched" text,
305
    "Author_score" double precision,
306
    "Family_matched" text,
307
    "Family_score" double precision,
308
    "Name_matched_accepted_family" text,
309
    "Genus_matched" text,
310
    "Genus_score" double precision,
311
    "Specific_epithet_matched" text,
312
    "Specific_epithet_score" double precision,
313
    "Infraspecific_rank" text,
314
    "Infraspecific_epithet_matched" text,
315
    "Infraspecific_epithet_score" double precision,
316
    "Infraspecific_rank_2" text,
317
    "Infraspecific_epithet_2_matched" text,
318
    "Infraspecific_epithet_2_score" double precision,
319
    "Annotations" text,
320
    "Unmatched_terms" text,
321
    "Taxonomic_status" text,
322
    "Accepted_name" text,
323
    "Accepted_name_author" text,
324
    "Accepted_name_rank" text,
325
    "Accepted_name_url" text,
326
    "Accepted_name_species" text,
327
    "Accepted_name_family" text,
328
    "Selected" text,
329
    "Source" text,
330
    "Warnings" text,
331
    "Accepted_name_lsid" text,
332
    is_valid_match boolean NOT NULL,
333
    scrubbed_unique_taxon_name text
334
);
335

    
336

    
337
--
338
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
339
--
340

    
341
COMMENT ON TABLE tnrs IS '
342
to remove columns or add columns at the end:
343
$ rm=1 inputs/.TNRS/data.sql.run
344
$ make schemas/remake
345

    
346
to add columns in the middle:
347
make the changes in inputs/.TNRS/schema.sql
348
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
349
$ make schemas/remake
350

    
351
to populate a new column:
352
ALTER TABLE "TNRS".tnrs DISABLE TRIGGER tnrs_populate_fields; --speeds up update
353
UPDATE "TNRS".tnrs SET "col" = value;
354
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
355
ALTER TABLE "TNRS".tnrs ENABLE TRIGGER tnrs_populate_fields;
356
VACUUM ANALYZE "TNRS".tnrs --remove previous rows; runtime: 1.5 min ("92633 ms")
357

    
358
to add a constraint: runtime: 3 min ("173620 ms")
359
';
360

    
361

    
362
--
363
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
364
--
365

    
366
CREATE VIEW "MatchedTaxon" AS
367
 SELECT s."*Name_matched.batch", 
368
    s."concatenatedScientificName", 
369
    s."matchedTaxonName", 
370
    s."matchedTaxonRank", 
371
    s."*Name_matched.Name_score", 
372
    s."matchedScientificNameAuthorship", 
373
    s."matchedScientificNameID", 
374
    s."*Name_matched.Author_score", 
375
    s."matchedFamilyConfidence_fraction", 
376
    s."matchedFamily", 
377
    s."matchedGenus", 
378
    s."matchedGenusConfidence_fraction", 
379
    s."matchedSpecificEpithet", 
380
    s."matchedSpeciesConfidence_fraction", 
381
    s."matchedInfraspecificEpithet", 
382
    s."*Name_matched.Infraspecific_epithet_score", 
383
    s."identificationQualifier", 
384
    s."morphospeciesSuffix", 
385
    s."taxonomicStatus", 
386
    s.accepted_taxon_name_no_author, 
387
    s.accepted_author, 
388
    s.accepted_taxon_rank, 
389
    s."acceptedScientificNameID", 
390
    s.accepted_species_binomial, 
391
    s.accepted_family, 
392
    s."*Name_matched.Selected", 
393
    s."*Name_matched.Source", 
394
    s."*Name_matched.Warnings", 
395
    s."*Name_matched.Accepted_name_lsid", 
396
    s.taxon_scrub__is_valid_match, 
397
    s.scrubbed_unique_taxon_name, 
398
        CASE
399
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
400
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
401
            ELSE s.accepted_species_binomial
402
        END AS accepted_morphospecies_binomial
403
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
404
            tnrs."Name_submitted" AS "concatenatedScientificName", 
405
            tnrs."Name_matched" AS "matchedTaxonName", 
406
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
407
            tnrs."Name_score" AS "*Name_matched.Name_score", 
408
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
409
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
410
            tnrs."Author_score" AS "*Name_matched.Author_score", 
411
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
412
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
413
            tnrs."Genus_matched" AS "matchedGenus", 
414
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
415
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
416
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
417
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
418
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
419
            tnrs."Annotations" AS "identificationQualifier", 
420
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
421
            map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus", 
422
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
423
            tnrs."Accepted_name_author" AS accepted_author, 
424
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
425
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
426
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
427
            tnrs."Accepted_name_family" AS accepted_family, 
428
            tnrs."Selected" AS "*Name_matched.Selected", 
429
            tnrs."Source" AS "*Name_matched.Source", 
430
            tnrs."Warnings" AS "*Name_matched.Warnings", 
431
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
432
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
433
            tnrs.scrubbed_unique_taxon_name
434
           FROM tnrs) s;
435

    
436

    
437
--
438
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
439
--
440

    
441
COMMENT ON VIEW "MatchedTaxon" IS '
442
to modify:
443
SELECT "TNRS"."MatchedTaxon_modify"($$
444
SELECT __
445
$$);
446
';
447

    
448

    
449
--
450
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
451
--
452

    
453
CREATE VIEW "ValidMatchedTaxon" AS
454
 SELECT "MatchedTaxon"."*Name_matched.batch", 
455
    "MatchedTaxon"."concatenatedScientificName", 
456
    "MatchedTaxon"."matchedTaxonName", 
457
    "MatchedTaxon"."matchedTaxonRank", 
458
    "MatchedTaxon"."*Name_matched.Name_score", 
459
    "MatchedTaxon"."matchedScientificNameAuthorship", 
460
    "MatchedTaxon"."matchedScientificNameID", 
461
    "MatchedTaxon"."*Name_matched.Author_score", 
462
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
463
    "MatchedTaxon"."matchedFamily", 
464
    "MatchedTaxon"."matchedGenus", 
465
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
466
    "MatchedTaxon"."matchedSpecificEpithet", 
467
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
468
    "MatchedTaxon"."matchedInfraspecificEpithet", 
469
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
470
    "MatchedTaxon"."identificationQualifier", 
471
    "MatchedTaxon"."morphospeciesSuffix", 
472
    "MatchedTaxon"."taxonomicStatus", 
473
    "MatchedTaxon".accepted_taxon_name_no_author, 
474
    "MatchedTaxon".accepted_author, 
475
    "MatchedTaxon".accepted_taxon_rank, 
476
    "MatchedTaxon"."acceptedScientificNameID", 
477
    "MatchedTaxon".accepted_species_binomial, 
478
    "MatchedTaxon".accepted_family, 
479
    "MatchedTaxon"."*Name_matched.Selected", 
480
    "MatchedTaxon"."*Name_matched.Source", 
481
    "MatchedTaxon"."*Name_matched.Warnings", 
482
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
483
    "MatchedTaxon".taxon_scrub__is_valid_match, 
484
    "MatchedTaxon".scrubbed_unique_taxon_name, 
485
    "MatchedTaxon".accepted_morphospecies_binomial
486
   FROM "MatchedTaxon"
487
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
488

    
489

    
490
--
491
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
492
--
493

    
494
COMMENT ON VIEW "ValidMatchedTaxon" IS '
495
to update, use * as the column list
496
';
497

    
498

    
499
--
500
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
501
--
502

    
503
CREATE TABLE batch (
504
    id text NOT NULL,
505
    id_by_time text,
506
    time_submitted timestamp with time zone DEFAULT now(),
507
    client_version text
508
);
509

    
510

    
511
--
512
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
513
--
514

    
515
CREATE TABLE batch_download_settings (
516
    id text NOT NULL,
517
    "E-mail" text,
518
    "Id" text,
519
    "Job type" text,
520
    "Contains Id" boolean,
521
    "Start time" text,
522
    "Finish time" text,
523
    "TNRS version" text,
524
    "Sources selected" text,
525
    "Match threshold" double precision,
526
    "Classification" text,
527
    "Allow partial matches?" boolean,
528
    "Sort by source" boolean,
529
    "Constrain by higher taxonomy" boolean
530
);
531

    
532

    
533
--
534
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
535
--
536

    
537
COMMENT ON TABLE batch_download_settings IS '
538
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
539
';
540

    
541

    
542
--
543
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
544
--
545

    
546
CREATE TABLE client_version (
547
    id text NOT NULL,
548
    global_rev integer NOT NULL,
549
    "/lib/tnrs.py rev" integer,
550
    "/bin/tnrs_db rev" integer
551
);
552

    
553

    
554
--
555
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
556
--
557

    
558
COMMENT ON TABLE client_version IS '
559
contains svn revisions
560
';
561

    
562

    
563
--
564
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
565
--
566

    
567
COMMENT ON COLUMN client_version.global_rev IS '
568
from `svn info .` > Last Changed Rev
569
';
570

    
571

    
572
--
573
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
574
--
575

    
576
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
577
from `svn info lib/tnrs.py` > Last Changed Rev
578
';
579

    
580

    
581
--
582
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
583
--
584

    
585
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
586
from `svn info bin/tnrs_db` > Last Changed Rev
587
';
588

    
589

    
590
--
591
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
592
--
593

    
594
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
595
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
596
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
597
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
598
    tnrs."Genus_matched" AS scrubbed_genus, 
599
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
600
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
601
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
602
    tnrs."Name_matched_author" AS scrubbed_author, 
603
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
604
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
605
   FROM tnrs;
606

    
607

    
608
--
609
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
610
--
611

    
612
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
613
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.
614
';
615

    
616

    
617
--
618
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
619
--
620

    
621
CREATE VIEW taxon_scrub AS
622
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
623
    "ValidMatchedTaxon"."*Name_matched.batch", 
624
    "ValidMatchedTaxon"."concatenatedScientificName", 
625
    "ValidMatchedTaxon"."matchedTaxonName", 
626
    "ValidMatchedTaxon"."matchedTaxonRank", 
627
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
628
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
629
    "ValidMatchedTaxon"."matchedScientificNameID", 
630
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
631
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
632
    "ValidMatchedTaxon"."matchedFamily", 
633
    "ValidMatchedTaxon"."matchedGenus", 
634
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
635
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
636
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
637
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
638
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
639
    "ValidMatchedTaxon"."identificationQualifier", 
640
    "ValidMatchedTaxon"."morphospeciesSuffix", 
641
    "ValidMatchedTaxon"."taxonomicStatus", 
642
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
643
    "ValidMatchedTaxon".accepted_author, 
644
    "ValidMatchedTaxon".accepted_taxon_rank, 
645
    "ValidMatchedTaxon"."acceptedScientificNameID", 
646
    "ValidMatchedTaxon".accepted_species_binomial, 
647
    "ValidMatchedTaxon".accepted_family, 
648
    "ValidMatchedTaxon"."*Name_matched.Selected", 
649
    "ValidMatchedTaxon"."*Name_matched.Source", 
650
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
651
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
652
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
653
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
654
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
655
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
656
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
657
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
658
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
659
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
660
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
661
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, 
662
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author, 
663
        CASE
664
            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")
665
            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")
666
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
667
        END AS scrubbed_morphospecies_binomial
668
   FROM ("ValidMatchedTaxon"
669
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
670

    
671

    
672
--
673
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
674
--
675

    
676
COMMENT ON VIEW taxon_scrub IS '
677
to modify:
678
SELECT "TNRS".taxon_scrub_modify($$
679
SELECT __
680
$$);
681
';
682

    
683

    
684
--
685
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
686
--
687

    
688
ALTER TABLE ONLY batch_download_settings
689
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
690

    
691

    
692
--
693
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
694
--
695

    
696
ALTER TABLE ONLY batch
697
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
698

    
699

    
700
--
701
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
702
--
703

    
704
ALTER TABLE ONLY batch
705
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
706

    
707

    
708
--
709
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
710
--
711

    
712
ALTER TABLE ONLY client_version
713
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
714

    
715

    
716
--
717
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
718
--
719

    
720
ALTER TABLE ONLY tnrs
721
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, match_num);
722

    
723

    
724
--
725
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
726
--
727

    
728
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
729

    
730

    
731
--
732
-- Name: tnrs_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
733
--
734

    
735
CREATE INDEX "tnrs_Name_submitted_idx" ON tnrs USING btree ("Name_submitted");
736

    
737

    
738
--
739
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
740
--
741

    
742
CREATE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
743

    
744

    
745
--
746
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
747
--
748

    
749
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
750

    
751

    
752
--
753
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
754
--
755

    
756
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
757

    
758

    
759
--
760
-- Name: tnrs__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
761
--
762

    
763
CREATE TRIGGER tnrs__match_num__fill BEFORE INSERT ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs__match_num__fill();
764

    
765

    
766
--
767
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
768
--
769

    
770
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
771

    
772

    
773
--
774
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
775
--
776

    
777
ALTER TABLE ONLY batch
778
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
779

    
780

    
781
--
782
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
783
--
784

    
785
ALTER TABLE ONLY batch_download_settings
786
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
787

    
788

    
789
--
790
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
791
--
792

    
793
ALTER TABLE ONLY tnrs
794
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
795

    
796

    
797
--
798
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
799
--
800

    
801
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
802
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
803
GRANT ALL ON SCHEMA "TNRS" TO bien;
804
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
805

    
806

    
807
--
808
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
809
--
810

    
811
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
812
REVOKE ALL ON TABLE tnrs FROM bien;
813
GRANT ALL ON TABLE tnrs TO bien;
814
GRANT SELECT ON TABLE tnrs TO bien_read;
815

    
816

    
817
--
818
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
819
--
820

    
821
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
822
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
823
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
824
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
825

    
826

    
827
--
828
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
829
--
830

    
831
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
832
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
833
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
834
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
835

    
836

    
837
--
838
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
839
--
840

    
841
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
842
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
843
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
844
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
845

    
846

    
847
--
848
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
849
--
850

    
851
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
852
REVOKE ALL ON TABLE taxon_scrub FROM bien;
853
GRANT ALL ON TABLE taxon_scrub TO bien;
854
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
855

    
856

    
857
--
858
-- PostgreSQL database dump complete
859
--
860

    
(8-8/10)