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".taxon_match'', 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: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47

    
48
CREATE FUNCTION batch__fill() RETURNS trigger
49
    LANGUAGE plpgsql
50
    AS $$
51
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
$$;
57

    
58

    
59
--
60
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
61
--
62

    
63
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

    
69

    
70
--
71
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
72
--
73

    
74
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

    
80

    
81
--
82
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
83
--
84

    
85
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
86
    LANGUAGE sql IMMUTABLE
87
    AS $_$
88
/* 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
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
92
$_$;
93

    
94

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

    
99
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
100
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
104
	RETURN NULL;
105
END;
106
$$;
107

    
108

    
109
--
110
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
111
--
112

    
113
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
114
    LANGUAGE sql IMMUTABLE
115
    AS $_$
116
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
117
$_$;
118

    
119

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

    
124
CREATE FUNCTION tnrs__batch_begin() RETURNS trigger
125
    LANGUAGE plpgsql
126
    AS $$
127
BEGIN
128
	PERFORM util.seq__reset('pg_temp.tnrs__match_num__seq', 0);
129
	RETURN NULL;
130
END;
131
$$;
132

    
133

    
134
--
135
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
136
--
137

    
138
CREATE FUNCTION tnrs__match_num__fill() RETURNS trigger
139
    LANGUAGE plpgsql
140
    AS $$
141
BEGIN
142
	IF new.match_num IS NULL THEN
143
		new.match_num = "TNRS".tnrs__match_num__next();
144
	END IF;
145
	RETURN new;
146
END;
147
$$;
148

    
149

    
150
--
151
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
152
--
153

    
154
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
155
    LANGUAGE sql
156
    AS $$
157
SELECT nextval('pg_temp.tnrs__match_num__seq');
158
$$;
159

    
160

    
161
--
162
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
163
--
164

    
165
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
166
    LANGUAGE plpgsql
167
    AS $$
168
DECLARE
169
	"Specific_epithet_is_plant" boolean :=
170
		(CASE
171
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
172
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
173
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
174
			THEN true
175
		ELSE NULL -- ambiguous
176
		END);
177
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
178
		-- author disambiguates
179
	family_is_homonym boolean = NOT never_homonym
180
		AND "TNRS".family_is_homonym(new."Family_matched");
181
	genus_is_homonym  boolean = NOT never_homonym
182
		AND "TNRS".genus_is_homonym(new."Genus_matched");
183
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
184
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
185
			new."Name_matched")
186
		, NULLIF(new."Name_matched", 'No suitable matches found.')
187
		, new."Name_matched_author"
188
		), '');
189
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
190
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
191
			new."Accepted_name")
192
		, new."Accepted_name"
193
		, new."Accepted_name_author"
194
		), '');
195
BEGIN
196
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
197
	a name, but the name is not meaningful because it is not unambiguous). */
198
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
199
		AND COALESCE(CASE
200
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
201
			THEN true
202
		ELSE -- consider genus
203
			(CASE
204
			WHEN new."Genus_score" =  1	   -- exact match
205
				THEN
206
				(CASE
207
				WHEN NOT genus_is_homonym THEN true
208
				ELSE "Specific_epithet_is_plant"
209
				END)
210
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
211
				THEN "Specific_epithet_is_plant"
212
			ELSE NULL -- ambiguous
213
			END)
214
		END, false);
215
	new.scrubbed_unique_taxon_name = COALESCE(
216
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
217
	
218
	RETURN new;
219
END;
220
$$;
221

    
222

    
223
--
224
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
225
--
226

    
227
COMMENT ON FUNCTION tnrs_populate_fields() IS '
228
IMPORTANT: when changing this function, you must regenerate the derived cols:
229
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
230
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
231
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
232
runtime: 1.5 min ("92633 ms")
233
';
234

    
235

    
236
--
237
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
238
--
239

    
240
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
241
    LANGUAGE sql IMMUTABLE
242
    AS $$
243
SELECT ARRAY[
244
]::text[]
245
$$;
246

    
247

    
248
SET default_tablespace = '';
249

    
250
SET default_with_oids = false;
251

    
252
--
253
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
254
--
255

    
256
CREATE TABLE taxon_match (
257
    batch text DEFAULT now() NOT NULL,
258
    match_num integer NOT NULL,
259
    "Name_number" integer NOT NULL,
260
    "Name_submitted" text NOT NULL,
261
    "Overall_score" double precision,
262
    "Name_matched" text,
263
    "Name_matched_rank" text,
264
    "Name_score" double precision,
265
    "Name_matched_author" text,
266
    "Name_matched_url" text,
267
    "Author_matched" text,
268
    "Author_score" double precision,
269
    "Family_matched" text,
270
    "Family_score" double precision,
271
    "Name_matched_accepted_family" text,
272
    "Genus_matched" text,
273
    "Genus_score" double precision,
274
    "Specific_epithet_matched" text,
275
    "Specific_epithet_score" double precision,
276
    "Infraspecific_rank" text,
277
    "Infraspecific_epithet_matched" text,
278
    "Infraspecific_epithet_score" double precision,
279
    "Infraspecific_rank_2" text,
280
    "Infraspecific_epithet_2_matched" text,
281
    "Infraspecific_epithet_2_score" double precision,
282
    "Annotations" text,
283
    "Unmatched_terms" text,
284
    "Taxonomic_status" text,
285
    "Accepted_name" text,
286
    "Accepted_name_author" text,
287
    "Accepted_name_rank" text,
288
    "Accepted_name_url" text,
289
    "Accepted_name_species" text,
290
    "Accepted_name_family" text,
291
    "Selected" text,
292
    "Source" text,
293
    "Warnings" text,
294
    "Accepted_name_lsid" text,
295
    is_valid_match boolean NOT NULL,
296
    scrubbed_unique_taxon_name text
297
);
298

    
299

    
300
--
301
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
302
--
303

    
304
COMMENT ON TABLE taxon_match IS '
305
to remove columns or add columns at the end:
306
$ rm=1 inputs/.TNRS/data.sql.run
307
$ make schemas/remake
308

    
309
to add columns in the middle:
310
make the changes in inputs/.TNRS/schema.sql
311
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
312
$ make schemas/remake
313

    
314
to populate a new column:
315
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER tnrs_populate_fields; --speeds up update
316
UPDATE "TNRS".taxon_match SET "col" = value;
317
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
318
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER tnrs_populate_fields;
319
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
320

    
321
to add a constraint: runtime: 3 min ("173620 ms")
322
';
323

    
324

    
325
--
326
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
327
--
328

    
329
CREATE VIEW "MatchedTaxon" AS
330
 SELECT s."*Name_matched.batch",
331
    s."concatenatedScientificName",
332
    s."matchedTaxonName",
333
    s."matchedTaxonRank",
334
    s."*Name_matched.Name_score",
335
    s."matchedScientificNameAuthorship",
336
    s."matchedScientificNameID",
337
    s."*Name_matched.Author_score",
338
    s."matchedFamilyConfidence_fraction",
339
    s."matchedFamily",
340
    s."matchedGenus",
341
    s."matchedGenusConfidence_fraction",
342
    s."matchedSpecificEpithet",
343
    s."matchedSpeciesConfidence_fraction",
344
    s."matchedInfraspecificEpithet",
345
    s."*Name_matched.Infraspecific_epithet_score",
346
    s."identificationQualifier",
347
    s."morphospeciesSuffix",
348
    s."taxonomicStatus",
349
    s.accepted_taxon_name_no_author,
350
    s.accepted_author,
351
    s.accepted_taxon_rank,
352
    s."acceptedScientificNameID",
353
    s.accepted_species_binomial,
354
    s.accepted_family,
355
    s."*Name_matched.Selected",
356
    s."*Name_matched.Source",
357
    s."*Name_matched.Warnings",
358
    s."*Name_matched.Accepted_name_lsid",
359
    s.taxon_scrub__is_valid_match,
360
    s.scrubbed_unique_taxon_name,
361
        CASE
362
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
363
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
364
            ELSE s.accepted_species_binomial
365
        END AS accepted_morphospecies_binomial
366
   FROM ( SELECT taxon_match.batch AS "*Name_matched.batch",
367
            taxon_match."Name_submitted" AS "concatenatedScientificName",
368
            taxon_match."Name_matched" AS "matchedTaxonName",
369
            taxon_match."Name_matched_rank" AS "matchedTaxonRank",
370
            taxon_match."Name_score" AS "*Name_matched.Name_score",
371
            taxon_match."Name_matched_author" AS "matchedScientificNameAuthorship",
372
            taxon_match."Name_matched_url" AS "matchedScientificNameID",
373
            taxon_match."Author_score" AS "*Name_matched.Author_score",
374
            taxon_match."Family_score" AS "matchedFamilyConfidence_fraction",
375
            COALESCE(taxon_match."Name_matched_accepted_family", taxon_match."Accepted_name_family") AS "matchedFamily",
376
            taxon_match."Genus_matched" AS "matchedGenus",
377
            taxon_match."Genus_score" AS "matchedGenusConfidence_fraction",
378
            taxon_match."Specific_epithet_matched" AS "matchedSpecificEpithet",
379
            taxon_match."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
380
            taxon_match."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
381
            taxon_match."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score",
382
            taxon_match."Annotations" AS "identificationQualifier",
383
            taxon_match."Unmatched_terms" AS "morphospeciesSuffix",
384
            map_taxonomic_status(taxon_match."Taxonomic_status", taxon_match."Accepted_name") AS "taxonomicStatus",
385
            taxon_match."Accepted_name" AS accepted_taxon_name_no_author,
386
            taxon_match."Accepted_name_author" AS accepted_author,
387
            taxon_match."Accepted_name_rank" AS accepted_taxon_rank,
388
            taxon_match."Accepted_name_url" AS "acceptedScientificNameID",
389
            taxon_match."Accepted_name_species" AS accepted_species_binomial,
390
            taxon_match."Accepted_name_family" AS accepted_family,
391
            taxon_match."Selected" AS "*Name_matched.Selected",
392
            taxon_match."Source" AS "*Name_matched.Source",
393
            taxon_match."Warnings" AS "*Name_matched.Warnings",
394
            taxon_match."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid",
395
            taxon_match.is_valid_match AS taxon_scrub__is_valid_match,
396
            taxon_match.scrubbed_unique_taxon_name
397
           FROM taxon_match) s;
398

    
399

    
400
--
401
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
402
--
403

    
404
COMMENT ON VIEW "MatchedTaxon" IS '
405
to modify:
406
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
407
SELECT __
408
$$);
409
';
410

    
411

    
412
--
413
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
414
--
415

    
416
CREATE VIEW "ValidMatchedTaxon" AS
417
 SELECT "MatchedTaxon"."*Name_matched.batch",
418
    "MatchedTaxon"."concatenatedScientificName",
419
    "MatchedTaxon"."matchedTaxonName",
420
    "MatchedTaxon"."matchedTaxonRank",
421
    "MatchedTaxon"."*Name_matched.Name_score",
422
    "MatchedTaxon"."matchedScientificNameAuthorship",
423
    "MatchedTaxon"."matchedScientificNameID",
424
    "MatchedTaxon"."*Name_matched.Author_score",
425
    "MatchedTaxon"."matchedFamilyConfidence_fraction",
426
    "MatchedTaxon"."matchedFamily",
427
    "MatchedTaxon"."matchedGenus",
428
    "MatchedTaxon"."matchedGenusConfidence_fraction",
429
    "MatchedTaxon"."matchedSpecificEpithet",
430
    "MatchedTaxon"."matchedSpeciesConfidence_fraction",
431
    "MatchedTaxon"."matchedInfraspecificEpithet",
432
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
433
    "MatchedTaxon"."identificationQualifier",
434
    "MatchedTaxon"."morphospeciesSuffix",
435
    "MatchedTaxon"."taxonomicStatus",
436
    "MatchedTaxon".accepted_taxon_name_no_author,
437
    "MatchedTaxon".accepted_author,
438
    "MatchedTaxon".accepted_taxon_rank,
439
    "MatchedTaxon"."acceptedScientificNameID",
440
    "MatchedTaxon".accepted_species_binomial,
441
    "MatchedTaxon".accepted_family,
442
    "MatchedTaxon"."*Name_matched.Selected",
443
    "MatchedTaxon"."*Name_matched.Source",
444
    "MatchedTaxon"."*Name_matched.Warnings",
445
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid",
446
    "MatchedTaxon".taxon_scrub__is_valid_match,
447
    "MatchedTaxon".scrubbed_unique_taxon_name,
448
    "MatchedTaxon".accepted_morphospecies_binomial
449
   FROM "MatchedTaxon"
450
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
451

    
452

    
453
--
454
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
455
--
456

    
457
COMMENT ON VIEW "ValidMatchedTaxon" IS '
458
to update, use * as the column list
459
';
460

    
461

    
462
--
463
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
464
--
465

    
466
CREATE TABLE batch (
467
    id text NOT NULL,
468
    id_by_time text,
469
    time_submitted timestamp with time zone DEFAULT now(),
470
    client_version text
471
);
472

    
473

    
474
--
475
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
476
--
477

    
478
CREATE TABLE batch_download_settings (
479
    id text NOT NULL,
480
    "E-mail" text,
481
    "Id" text,
482
    "Job type" text,
483
    "Contains Id" boolean,
484
    "Start time" text,
485
    "Finish time" text,
486
    "TNRS version" text,
487
    "Sources selected" text,
488
    "Match threshold" double precision,
489
    "Classification" text,
490
    "Allow partial matches?" boolean,
491
    "Sort by source" boolean,
492
    "Constrain by higher taxonomy" boolean
493
);
494

    
495

    
496
--
497
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
498
--
499

    
500
COMMENT ON TABLE batch_download_settings IS '
501
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
502
';
503

    
504

    
505
--
506
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
507
--
508

    
509
CREATE TABLE client_version (
510
    id text NOT NULL,
511
    global_rev integer NOT NULL,
512
    "/lib/tnrs.py rev" integer,
513
    "/bin/tnrs_db rev" integer
514
);
515

    
516

    
517
--
518
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
519
--
520

    
521
COMMENT ON TABLE client_version IS '
522
contains svn revisions
523
';
524

    
525

    
526
--
527
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
528
--
529

    
530
COMMENT ON COLUMN client_version.global_rev IS '
531
from `svn info .` > Last Changed Rev
532
';
533

    
534

    
535
--
536
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
537
--
538

    
539
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
540
from `svn info lib/tnrs.py` > Last Changed Rev
541
';
542

    
543

    
544
--
545
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
546
--
547

    
548
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
549
from `svn info bin/tnrs_db` > Last Changed Rev
550
';
551

    
552

    
553
--
554
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
555
--
556

    
557
CREATE VIEW taxon_match_input AS
558
 SELECT taxon_match."Name_number",
559
    taxon_match."Name_submitted",
560
    taxon_match."Overall_score",
561
    taxon_match."Name_matched",
562
    taxon_match."Name_matched_rank",
563
    taxon_match."Name_score",
564
    taxon_match."Name_matched_author",
565
    taxon_match."Name_matched_url",
566
    taxon_match."Author_matched",
567
    taxon_match."Author_score",
568
    taxon_match."Family_matched",
569
    taxon_match."Family_score",
570
    taxon_match."Name_matched_accepted_family",
571
    taxon_match."Genus_matched",
572
    taxon_match."Genus_score",
573
    taxon_match."Specific_epithet_matched",
574
    taxon_match."Specific_epithet_score",
575
    taxon_match."Infraspecific_rank",
576
    taxon_match."Infraspecific_epithet_matched",
577
    taxon_match."Infraspecific_epithet_score",
578
    taxon_match."Infraspecific_rank_2",
579
    taxon_match."Infraspecific_epithet_2_matched",
580
    taxon_match."Infraspecific_epithet_2_score",
581
    taxon_match."Annotations",
582
    taxon_match."Unmatched_terms",
583
    taxon_match."Taxonomic_status",
584
    taxon_match."Accepted_name",
585
    taxon_match."Accepted_name_author",
586
    taxon_match."Accepted_name_rank",
587
    taxon_match."Accepted_name_url",
588
    taxon_match."Accepted_name_species",
589
    taxon_match."Accepted_name_family",
590
    taxon_match."Selected",
591
    taxon_match."Source",
592
    taxon_match."Warnings",
593
    taxon_match."Accepted_name_lsid"
594
   FROM taxon_match;
595

    
596

    
597
--
598
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
599
--
600

    
601
CREATE TABLE taxon_match_input__copy_to (
602
    "Name_number" integer,
603
    "Name_submitted" text,
604
    "Overall_score" double precision,
605
    "Name_matched" text,
606
    "Name_matched_rank" text,
607
    "Name_score" double precision,
608
    "Name_matched_author" text,
609
    "Name_matched_url" text,
610
    "Author_matched" text,
611
    "Author_score" double precision,
612
    "Family_matched" text,
613
    "Family_score" double precision,
614
    "Name_matched_accepted_family" text,
615
    "Genus_matched" text,
616
    "Genus_score" double precision,
617
    "Specific_epithet_matched" text,
618
    "Specific_epithet_score" double precision,
619
    "Infraspecific_rank" text,
620
    "Infraspecific_epithet_matched" text,
621
    "Infraspecific_epithet_score" double precision,
622
    "Infraspecific_rank_2" text,
623
    "Infraspecific_epithet_2_matched" text,
624
    "Infraspecific_epithet_2_score" double precision,
625
    "Annotations" text,
626
    "Unmatched_terms" text,
627
    "Taxonomic_status" text,
628
    "Accepted_name" text,
629
    "Accepted_name_author" text,
630
    "Accepted_name_rank" text,
631
    "Accepted_name_url" text,
632
    "Accepted_name_species" text,
633
    "Accepted_name_family" text,
634
    "Selected" text,
635
    "Source" text,
636
    "Warnings" text,
637
    "Accepted_name_lsid" text
638
);
639

    
640

    
641
--
642
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
643
--
644

    
645
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
646
 SELECT taxon_match."Name_submitted" AS scrubbed_unique_taxon_name,
647
    taxon_match."Name_matched_rank" AS scrubbed_taxon_rank,
648
    COALESCE(taxon_match."Name_matched_accepted_family", taxon_match."Family_matched") AS scrubbed_family,
649
    taxon_match."Genus_matched" AS scrubbed_genus,
650
    taxon_match."Specific_epithet_matched" AS scrubbed_specific_epithet,
651
    taxon_match."Infraspecific_rank" AS scrubbed_infraspecific_rank,
652
    taxon_match."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
653
    taxon_match."Name_matched_author" AS scrubbed_author,
654
    taxon_match."Name_matched" AS scrubbed_taxon_name_no_author,
655
    (taxon_match."Name_matched" || COALESCE((' '::text || taxon_match."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
656
   FROM taxon_match;
657

    
658

    
659
--
660
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
661
--
662

    
663
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
664
to modify:
665
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
666
SELECT __
667
$$);
668

    
669
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.
670
';
671

    
672

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

    
677
CREATE VIEW taxon_scrub AS
678
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
679
    "ValidMatchedTaxon"."*Name_matched.batch",
680
    "ValidMatchedTaxon"."concatenatedScientificName",
681
    "ValidMatchedTaxon"."matchedTaxonName",
682
    "ValidMatchedTaxon"."matchedTaxonRank",
683
    "ValidMatchedTaxon"."*Name_matched.Name_score",
684
    "ValidMatchedTaxon"."matchedScientificNameAuthorship",
685
    "ValidMatchedTaxon"."matchedScientificNameID",
686
    "ValidMatchedTaxon"."*Name_matched.Author_score",
687
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
688
    "ValidMatchedTaxon"."matchedFamily",
689
    "ValidMatchedTaxon"."matchedGenus",
690
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction",
691
    "ValidMatchedTaxon"."matchedSpecificEpithet",
692
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
693
    "ValidMatchedTaxon"."matchedInfraspecificEpithet",
694
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
695
    "ValidMatchedTaxon"."identificationQualifier",
696
    "ValidMatchedTaxon"."morphospeciesSuffix",
697
    "ValidMatchedTaxon"."taxonomicStatus",
698
    "ValidMatchedTaxon".accepted_taxon_name_no_author,
699
    "ValidMatchedTaxon".accepted_author,
700
    "ValidMatchedTaxon".accepted_taxon_rank,
701
    "ValidMatchedTaxon"."acceptedScientificNameID",
702
    "ValidMatchedTaxon".accepted_species_binomial,
703
    "ValidMatchedTaxon".accepted_family,
704
    "ValidMatchedTaxon"."*Name_matched.Selected",
705
    "ValidMatchedTaxon"."*Name_matched.Source",
706
    "ValidMatchedTaxon"."*Name_matched.Warnings",
707
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid",
708
    "ValidMatchedTaxon".taxon_scrub__is_valid_match,
709
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
710
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
711
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
712
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
713
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
714
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
715
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
716
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
717
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
718
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
719
        CASE
720
            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")
721
            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")
722
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
723
        END AS scrubbed_morphospecies_binomial
724
   FROM ("ValidMatchedTaxon"
725
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
726

    
727

    
728
--
729
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
730
--
731

    
732
COMMENT ON VIEW taxon_scrub IS '
733
to modify:
734
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
735
SELECT __
736
$$);
737
';
738

    
739

    
740
--
741
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
742
--
743

    
744
ALTER TABLE ONLY batch_download_settings
745
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
746

    
747

    
748
--
749
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
750
--
751

    
752
ALTER TABLE ONLY batch
753
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
754

    
755

    
756
--
757
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
758
--
759

    
760
ALTER TABLE ONLY batch
761
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
762

    
763

    
764
--
765
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
766
--
767

    
768
ALTER TABLE ONLY client_version
769
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
770

    
771

    
772
--
773
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
774
--
775

    
776
ALTER TABLE ONLY taxon_match
777
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, match_num);
778

    
779

    
780
--
781
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
782
--
783

    
784
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
785

    
786

    
787
--
788
-- Name: tnrs_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
789
--
790

    
791
CREATE INDEX "tnrs_Name_submitted_idx" ON taxon_match USING btree ("Name_submitted");
792

    
793

    
794
--
795
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
796
--
797

    
798
CREATE INDEX tnrs__valid_match ON taxon_match USING btree ("Name_submitted") WHERE is_valid_match;
799

    
800

    
801
--
802
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
803
--
804

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

    
807

    
808
--
809
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
810
--
811

    
812
CREATE TRIGGER taxon_match_input__copy_to__insert BEFORE INSERT ON taxon_match_input__copy_to FOR EACH ROW EXECUTE PROCEDURE taxon_match_input__copy_to__insert();
813

    
814

    
815
--
816
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
817
--
818

    
819
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
820

    
821

    
822
--
823
-- Name: tnrs__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
824
--
825

    
826
CREATE TRIGGER tnrs__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE tnrs__match_num__fill();
827

    
828

    
829
--
830
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
831
--
832

    
833
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
834

    
835

    
836
--
837
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
838
--
839

    
840
ALTER TABLE ONLY batch
841
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
842

    
843

    
844
--
845
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
846
--
847

    
848
ALTER TABLE ONLY batch_download_settings
849
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
850

    
851

    
852
--
853
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
854
--
855

    
856
ALTER TABLE ONLY taxon_match
857
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
858

    
859

    
860
--
861
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
862
--
863

    
864
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
865
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
866
GRANT ALL ON SCHEMA "TNRS" TO bien;
867
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
868

    
869

    
870
--
871
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
872
--
873

    
874
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
875
REVOKE ALL ON TABLE taxon_match FROM bien;
876
GRANT ALL ON TABLE taxon_match TO bien;
877
GRANT SELECT ON TABLE taxon_match TO bien_read;
878

    
879

    
880
--
881
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
882
--
883

    
884
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
885
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
886
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
887
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
888

    
889

    
890
--
891
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
892
--
893

    
894
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
895
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
896
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
897
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
898

    
899

    
900
--
901
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
902
--
903

    
904
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
905
REVOKE ALL ON TABLE taxon_match_input FROM bien;
906
GRANT ALL ON TABLE taxon_match_input TO bien;
907
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
908

    
909

    
910
--
911
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
912
--
913

    
914
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
915
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
916
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
917
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
918

    
919

    
920
--
921
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
922
--
923

    
924
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
925
REVOKE ALL ON TABLE taxon_scrub FROM bien;
926
GRANT ALL ON TABLE taxon_scrub TO bien;
927
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
928

    
929

    
930
--
931
-- PostgreSQL database dump complete
932
--
933

    
(8-8/10)