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
]::text[]
281
$$;
282

    
283

    
284
SET default_tablespace = '';
285

    
286
SET default_with_oids = false;
287

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

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

    
335

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

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

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

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

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

    
360

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

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

    
435

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

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

    
447

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

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

    
488

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

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

    
497

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

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

    
509

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

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

    
531

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

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

    
540

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

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

    
552

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

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

    
561

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

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

    
570

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

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

    
579

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

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

    
588

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

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

    
606

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

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

    
615

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

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

    
670

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

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

    
682

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

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

    
690

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

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

    
698

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

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

    
706

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

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

    
714

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

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

    
722

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

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

    
729

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

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

    
736

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

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

    
743

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

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

    
750

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

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

    
757

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

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

    
764

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

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

    
771

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

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

    
779

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

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

    
787

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

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

    
795

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

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

    
805

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

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

    
815

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

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

    
825

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

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

    
835

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

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

    
845

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

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

    
855

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

    
(8-8/10)