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) RETURNS void
49
    LANGUAGE sql
50
    AS $_$
51
SELECT util.recreate_view('"TNRS"."MatchedTaxon"', $1, $$
52
-- **IMPORTANT**: keep these updated as described in the views' comments
53

    
54
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
55
 SELECT *
56
   FROM "TNRS"."MatchedTaxon"
57
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
58
$$||util.mk_set_relation_metadata('"TNRS"."ValidMatchedTaxon"')||$$
59

    
60
CREATE VIEW "TNRS".taxon_scrub AS 
61
 SELECT *
62
   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
-- 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
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
86
--
87

    
88
CREATE FUNCTION batch__fill() RETURNS trigger
89
    LANGUAGE plpgsql
90
    AS $$
91
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
$$;
97

    
98

    
99
--
100
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
101
--
102

    
103
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

    
109

    
110
--
111
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
112
--
113

    
114
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

    
120

    
121
--
122
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
123
--
124

    
125
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
126
    LANGUAGE sql IMMUTABLE
127
    AS $_$
128
/* 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
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
132
$_$;
133

    
134

    
135
--
136
-- 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
 SELECT *, __ AS scrubbed_morphospecies_binomial
154
   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
-- 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
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
178
--
179

    
180
CREATE FUNCTION tnrs__match_num__fill() RETURNS trigger
181
    LANGUAGE plpgsql
182
    AS $$
183
BEGIN
184
	new.match_num = "TNRS".tnrs__match_num__next();
185
	RETURN new;
186
END;
187
$$;
188

    
189

    
190
--
191
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
192
--
193

    
194
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
195
    LANGUAGE sql
196
    AS $$
197
SELECT nextval('pg_temp.tnrs__match_num__seq');
198
$$;
199

    
200

    
201
--
202
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
203
--
204

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

    
262

    
263
--
264
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
265
--
266

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

    
275

    
276
SET default_tablespace = '';
277

    
278
SET default_with_oids = false;
279

    
280
--
281
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
282
--
283

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

    
327

    
328
--
329
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
330
--
331

    
332
COMMENT ON TABLE tnrs IS '
333
to remove columns or add columns at the end:
334
$ rm=1 inputs/.TNRS/data.sql.run
335
$ make schemas/remake
336

    
337
to add columns in the middle:
338
make the changes in inputs/.TNRS/schema.sql
339
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
340
$ make schemas/remake
341
';
342

    
343

    
344
--
345
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
346
--
347

    
348
CREATE VIEW "MatchedTaxon" AS
349
 SELECT s."*Name_matched.batch", 
350
    s."concatenatedScientificName", 
351
    s."matchedTaxonName", 
352
    s."matchedTaxonRank", 
353
    s."*Name_matched.Name_score", 
354
    s."matchedScientificNameAuthorship", 
355
    s."matchedScientificNameID", 
356
    s."*Name_matched.Author_score", 
357
    s."matchedFamilyConfidence_fraction", 
358
    s."matchedFamily", 
359
    s."matchedGenus", 
360
    s."matchedGenusConfidence_fraction", 
361
    s."matchedSpecificEpithet", 
362
    s."matchedSpeciesConfidence_fraction", 
363
    s."matchedInfraspecificEpithet", 
364
    s."*Name_matched.Infraspecific_epithet_score", 
365
    s."identificationQualifier", 
366
    s."morphospeciesSuffix", 
367
    s."taxonomicStatus", 
368
    s.accepted_taxon_name_no_author, 
369
    s.accepted_author, 
370
    s.accepted_taxon_rank, 
371
    s."acceptedScientificNameID", 
372
    s.accepted_species_binomial, 
373
    s.accepted_family, 
374
    s."*Name_matched.Selected", 
375
    s."*Name_matched.Source", 
376
    s."*Name_matched.Warnings", 
377
    s."*Name_matched.Accepted_name_lsid", 
378
    s.taxon_scrub__is_valid_match, 
379
    s.scrubbed_unique_taxon_name, 
380
        CASE
381
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
382
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
383
            ELSE s.accepted_species_binomial
384
        END AS accepted_morphospecies_binomial
385
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
386
            tnrs."Name_submitted" AS "concatenatedScientificName", 
387
            tnrs."Name_matched" AS "matchedTaxonName", 
388
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
389
            tnrs."Name_score" AS "*Name_matched.Name_score", 
390
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
391
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
392
            tnrs."Author_score" AS "*Name_matched.Author_score", 
393
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
394
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
395
            tnrs."Genus_matched" AS "matchedGenus", 
396
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
397
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
398
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
399
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
400
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
401
            tnrs."Annotations" AS "identificationQualifier", 
402
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
403
            map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus", 
404
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
405
            tnrs."Accepted_name_author" AS accepted_author, 
406
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
407
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
408
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
409
            tnrs."Accepted_name_family" AS accepted_family, 
410
            tnrs."Selected" AS "*Name_matched.Selected", 
411
            tnrs."Source" AS "*Name_matched.Source", 
412
            tnrs."Warnings" AS "*Name_matched.Warnings", 
413
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
414
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
415
            tnrs.scrubbed_unique_taxon_name
416
           FROM tnrs) s;
417

    
418

    
419
--
420
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
421
--
422

    
423
COMMENT ON VIEW "MatchedTaxon" IS '
424
to modify:
425
SELECT "TNRS"."MatchedTaxon_modify"($$
426
 SELECT *, __ AS accepted_morphospecies_binomial
427
   FROM __
428
$$);
429
';
430

    
431

    
432
--
433
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
434
--
435

    
436
CREATE VIEW "ValidMatchedTaxon" AS
437
 SELECT "MatchedTaxon"."*Name_matched.batch", 
438
    "MatchedTaxon"."concatenatedScientificName", 
439
    "MatchedTaxon"."matchedTaxonName", 
440
    "MatchedTaxon"."matchedTaxonRank", 
441
    "MatchedTaxon"."*Name_matched.Name_score", 
442
    "MatchedTaxon"."matchedScientificNameAuthorship", 
443
    "MatchedTaxon"."matchedScientificNameID", 
444
    "MatchedTaxon"."*Name_matched.Author_score", 
445
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
446
    "MatchedTaxon"."matchedFamily", 
447
    "MatchedTaxon"."matchedGenus", 
448
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
449
    "MatchedTaxon"."matchedSpecificEpithet", 
450
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
451
    "MatchedTaxon"."matchedInfraspecificEpithet", 
452
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
453
    "MatchedTaxon"."identificationQualifier", 
454
    "MatchedTaxon"."morphospeciesSuffix", 
455
    "MatchedTaxon"."taxonomicStatus", 
456
    "MatchedTaxon".accepted_taxon_name_no_author, 
457
    "MatchedTaxon".accepted_author, 
458
    "MatchedTaxon".accepted_taxon_rank, 
459
    "MatchedTaxon"."acceptedScientificNameID", 
460
    "MatchedTaxon".accepted_species_binomial, 
461
    "MatchedTaxon".accepted_family, 
462
    "MatchedTaxon"."*Name_matched.Selected", 
463
    "MatchedTaxon"."*Name_matched.Source", 
464
    "MatchedTaxon"."*Name_matched.Warnings", 
465
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
466
    "MatchedTaxon".taxon_scrub__is_valid_match, 
467
    "MatchedTaxon".scrubbed_unique_taxon_name, 
468
    "MatchedTaxon".accepted_morphospecies_binomial
469
   FROM "MatchedTaxon"
470
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
471

    
472

    
473
--
474
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
475
--
476

    
477
COMMENT ON VIEW "ValidMatchedTaxon" IS '
478
to update, use * as the column list
479
';
480

    
481

    
482
--
483
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
484
--
485

    
486
CREATE TABLE batch (
487
    id text NOT NULL,
488
    id_by_time text,
489
    time_submitted timestamp with time zone DEFAULT now(),
490
    client_version text
491
);
492

    
493

    
494
--
495
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
496
--
497

    
498
CREATE TABLE batch_download_settings (
499
    id text NOT NULL,
500
    "E-mail" text,
501
    "Id" text,
502
    "Job type" text,
503
    "Contains Id" boolean,
504
    "Start time" text,
505
    "Finish time" text,
506
    "TNRS version" text,
507
    "Sources selected" text,
508
    "Match threshold" double precision,
509
    "Classification" text,
510
    "Allow partial matches?" boolean,
511
    "Sort by source" boolean,
512
    "Constrain by higher taxonomy" boolean
513
);
514

    
515

    
516
--
517
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
518
--
519

    
520
COMMENT ON TABLE batch_download_settings IS '
521
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
522
';
523

    
524

    
525
--
526
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
527
--
528

    
529
CREATE TABLE client_version (
530
    id text NOT NULL,
531
    global_rev integer NOT NULL,
532
    "/lib/tnrs.py rev" integer,
533
    "/bin/tnrs_db rev" integer
534
);
535

    
536

    
537
--
538
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
539
--
540

    
541
COMMENT ON TABLE client_version IS '
542
contains svn revisions
543
';
544

    
545

    
546
--
547
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
548
--
549

    
550
COMMENT ON COLUMN client_version.global_rev IS '
551
from `svn info .` > Last Changed Rev
552
';
553

    
554

    
555
--
556
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
557
--
558

    
559
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
560
from `svn info lib/tnrs.py` > Last Changed Rev
561
';
562

    
563

    
564
--
565
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
566
--
567

    
568
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
569
from `svn info bin/tnrs_db` > Last Changed Rev
570
';
571

    
572

    
573
--
574
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
575
--
576

    
577
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
578
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
579
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
580
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
581
    tnrs."Genus_matched" AS scrubbed_genus, 
582
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
583
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
584
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
585
    tnrs."Name_matched_author" AS scrubbed_author, 
586
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
587
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
588
   FROM tnrs;
589

    
590

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

    
595
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
596
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.
597
';
598

    
599

    
600
--
601
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
602
--
603

    
604
CREATE VIEW taxon_scrub AS
605
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
606
    "ValidMatchedTaxon"."*Name_matched.batch", 
607
    "ValidMatchedTaxon"."concatenatedScientificName", 
608
    "ValidMatchedTaxon"."matchedTaxonName", 
609
    "ValidMatchedTaxon"."matchedTaxonRank", 
610
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
611
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
612
    "ValidMatchedTaxon"."matchedScientificNameID", 
613
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
614
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
615
    "ValidMatchedTaxon"."matchedFamily", 
616
    "ValidMatchedTaxon"."matchedGenus", 
617
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
618
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
619
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
620
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
621
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
622
    "ValidMatchedTaxon"."identificationQualifier", 
623
    "ValidMatchedTaxon"."morphospeciesSuffix", 
624
    "ValidMatchedTaxon"."taxonomicStatus", 
625
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
626
    "ValidMatchedTaxon".accepted_author, 
627
    "ValidMatchedTaxon".accepted_taxon_rank, 
628
    "ValidMatchedTaxon"."acceptedScientificNameID", 
629
    "ValidMatchedTaxon".accepted_species_binomial, 
630
    "ValidMatchedTaxon".accepted_family, 
631
    "ValidMatchedTaxon"."*Name_matched.Selected", 
632
    "ValidMatchedTaxon"."*Name_matched.Source", 
633
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
634
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
635
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
636
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
637
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
638
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
639
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
640
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
641
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
642
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
643
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
644
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, 
645
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author, 
646
        CASE
647
            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")
648
            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")
649
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
650
        END AS scrubbed_morphospecies_binomial
651
   FROM ("ValidMatchedTaxon"
652
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
653

    
654

    
655
--
656
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
657
--
658

    
659
COMMENT ON VIEW taxon_scrub IS '
660
to modify:
661
SELECT "TNRS".taxon_scrub_modify($$
662
 SELECT *, __ AS scrubbed_morphospecies_binomial
663
   FROM "TNRS"."ValidMatchedTaxon"
664
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
665
$$);
666
';
667

    
668

    
669
--
670
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
671
--
672

    
673
ALTER TABLE ONLY batch_download_settings
674
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
675

    
676

    
677
--
678
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
679
--
680

    
681
ALTER TABLE ONLY batch
682
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
683

    
684

    
685
--
686
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
687
--
688

    
689
ALTER TABLE ONLY batch
690
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
691

    
692

    
693
--
694
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
695
--
696

    
697
ALTER TABLE ONLY client_version
698
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
699

    
700

    
701
--
702
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
703
--
704

    
705
ALTER TABLE ONLY tnrs
706
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
707

    
708

    
709
--
710
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
711
--
712

    
713
ALTER TABLE ONLY tnrs
714
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, match_num);
715

    
716

    
717
--
718
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
719
--
720

    
721
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
722

    
723

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

    
728
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
729

    
730

    
731
--
732
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
733
--
734

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

    
737

    
738
--
739
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
740
--
741

    
742
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
743

    
744

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

    
749
CREATE TRIGGER tnrs__match_num__fill BEFORE INSERT ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs__match_num__fill();
750

    
751

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

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

    
758

    
759
--
760
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
761
--
762

    
763
ALTER TABLE ONLY batch
764
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
765

    
766

    
767
--
768
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
769
--
770

    
771
ALTER TABLE ONLY batch_download_settings
772
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
773

    
774

    
775
--
776
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
777
--
778

    
779
ALTER TABLE ONLY tnrs
780
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
781

    
782

    
783
--
784
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
785
--
786

    
787
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
788
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
789
GRANT ALL ON SCHEMA "TNRS" TO bien;
790
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
791

    
792

    
793
--
794
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
795
--
796

    
797
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
798
REVOKE ALL ON TABLE tnrs FROM bien;
799
GRANT ALL ON TABLE tnrs TO bien;
800
GRANT SELECT ON TABLE tnrs TO bien_read;
801

    
802

    
803
--
804
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
805
--
806

    
807
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
808
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
809
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
810
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
811

    
812

    
813
--
814
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
815
--
816

    
817
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
818
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
819
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
820
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
821

    
822

    
823
--
824
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
825
--
826

    
827
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
828
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
829
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
830
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
831

    
832

    
833
--
834
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
835
--
836

    
837
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
838
REVOKE ALL ON TABLE taxon_scrub FROM bien;
839
GRANT ALL ON TABLE taxon_scrub TO bien;
840
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
841

    
842

    
843
--
844
-- PostgreSQL database dump complete
845
--
846

    
(8-8/10)