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__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
97
--
98

    
99
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
100
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103
	PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
104
	RETURN NULL;
105
END;
106
$$;
107

    
108

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

    
113
CREATE FUNCTION taxon_match__fill() RETURNS trigger
114
    LANGUAGE plpgsql
115
    AS $$
116
BEGIN
117
	DECLARE
118
		"Specific_epithet_is_plant" boolean :=
119
			(CASE
120
			WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
121
				OR new."Infraspecific_epithet_2_matched" IS NOT NULL
122
				OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
123
				THEN true
124
			ELSE NULL -- ambiguous
125
			END);
126
		never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
127
			-- author disambiguates
128
		family_is_homonym boolean = NOT never_homonym
129
			AND "TNRS".family_is_homonym(new."Family_matched");
130
		genus_is_homonym  boolean = NOT never_homonym
131
			AND "TNRS".genus_is_homonym(new."Genus_matched");
132
	BEGIN
133
		/* exclude homonyms because these are not valid matches (TNRS provides a
134
		name, but the name is not meaningful because it is not unambiguous) */
135
		new.is_valid_match = new."Taxonomic_status" != 'Invalid'
136
			AND COALESCE(CASE
137
			WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
138
				THEN true
139
			ELSE -- consider genus
140
				(CASE
141
				WHEN new."Genus_score" =  1	   -- exact match
142
					THEN
143
					(CASE
144
					WHEN NOT genus_is_homonym THEN true
145
					ELSE "Specific_epithet_is_plant"
146
					END)
147
				WHEN new."Genus_score" >= 0.85 -- fuzzy match
148
					THEN "Specific_epithet_is_plant"
149
				ELSE NULL -- ambiguous
150
				END)
151
			END, false);
152
	END;
153
	
154
	DECLARE
155
		matched_taxon_name_with_author text = NULLIF(concat_ws(' '
156
			, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
157
				new."Name_matched")
158
			, NULLIF(new."Name_matched", 'No suitable matches found.')
159
			, new."Name_matched_author"
160
			), '');
161
		accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
162
			, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
163
				new."Accepted_name")
164
			, new."Accepted_name"
165
			, new."Accepted_name_author"
166
			), '');
167
	BEGIN
168
		new.scrubbed_unique_taxon_name = COALESCE(
169
			accepted_taxon_name_with_author, matched_taxon_name_with_author);
170
	END;
171
	
172
	RETURN new;
173
END;
174
$$;
175

    
176

    
177
--
178
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
179
--
180

    
181
COMMENT ON FUNCTION taxon_match__fill() IS '
182
IMPORTANT: when changing this function, you must regenerate the derived cols:
183
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
184
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
185
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
186
runtime: 1.5 min ("92633 ms")
187
';
188

    
189

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

    
194
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
195
    LANGUAGE plpgsql
196
    AS $$
197
BEGIN
198
	IF new.match_num IS NULL THEN
199
		new.match_num = "TNRS".taxon_match__match_num__next();
200
	END IF;
201
	RETURN new;
202
END;
203
$$;
204

    
205

    
206
--
207
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
208
--
209

    
210
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
211
    LANGUAGE sql
212
    AS $$
213
SELECT nextval('pg_temp.taxon_match__match_num__seq');
214
$$;
215

    
216

    
217
--
218
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
219
--
220

    
221
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
222
    LANGUAGE plpgsql
223
    AS $$
224
BEGIN
225
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
226
	RETURN NULL;
227
END;
228
$$;
229

    
230

    
231
--
232
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
233
--
234

    
235
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
236
    LANGUAGE sql IMMUTABLE
237
    AS $_$
238
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
239
$_$;
240

    
241

    
242
--
243
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
244
--
245

    
246
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
247
    LANGUAGE sql IMMUTABLE
248
    AS $$
249
SELECT ARRAY[
250
]::text[]
251
$$;
252

    
253

    
254
SET default_tablespace = '';
255

    
256
SET default_with_oids = false;
257

    
258
--
259
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
260
--
261

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

    
305

    
306
--
307
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
308
--
309

    
310
COMMENT ON TABLE taxon_match IS '
311
to remove columns or add columns at the end:
312
$ rm=1 inputs/.TNRS/data.sql.run
313
$ make schemas/remake
314

    
315
to add columns in the middle:
316
make the changes in inputs/.TNRS/schema.sql
317
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
318
$ make schemas/remake
319

    
320
to populate a new column:
321
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
322
UPDATE "TNRS".taxon_match SET "col" = value;
323
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
324
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
325
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
326

    
327
to add a constraint: runtime: 3 min ("173620 ms")
328
';
329

    
330

    
331
--
332
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
333
--
334

    
335
CREATE VIEW taxon_best_match AS
336
 SELECT taxon_match.batch,
337
    taxon_match.match_num,
338
    taxon_match."Name_number",
339
    taxon_match."Name_submitted",
340
    taxon_match."Overall_score",
341
    taxon_match."Name_matched",
342
    taxon_match."Name_matched_rank",
343
    taxon_match."Name_score",
344
    taxon_match."Name_matched_author",
345
    taxon_match."Name_matched_url",
346
    taxon_match."Author_matched",
347
    taxon_match."Author_score",
348
    taxon_match."Family_matched",
349
    taxon_match."Family_score",
350
    taxon_match."Name_matched_accepted_family",
351
    taxon_match."Genus_matched",
352
    taxon_match."Genus_score",
353
    taxon_match."Specific_epithet_matched",
354
    taxon_match."Specific_epithet_score",
355
    taxon_match."Infraspecific_rank",
356
    taxon_match."Infraspecific_epithet_matched",
357
    taxon_match."Infraspecific_epithet_score",
358
    taxon_match."Infraspecific_rank_2",
359
    taxon_match."Infraspecific_epithet_2_matched",
360
    taxon_match."Infraspecific_epithet_2_score",
361
    taxon_match."Annotations",
362
    taxon_match."Unmatched_terms",
363
    taxon_match."Taxonomic_status",
364
    taxon_match."Accepted_name",
365
    taxon_match."Accepted_name_author",
366
    taxon_match."Accepted_name_rank",
367
    taxon_match."Accepted_name_url",
368
    taxon_match."Accepted_name_species",
369
    taxon_match."Accepted_name_family",
370
    taxon_match."Selected",
371
    taxon_match."Source",
372
    taxon_match."Warnings",
373
    taxon_match."Accepted_name_lsid",
374
    taxon_match.is_valid_match,
375
    taxon_match.scrubbed_unique_taxon_name
376
   FROM taxon_match
377
  WHERE (taxon_match."Selected" = 'true'::text);
378

    
379

    
380
--
381
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
382
--
383

    
384
COMMENT ON VIEW taxon_best_match IS '
385
to modify:
386
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
387
SELECT __
388
$$);
389
';
390

    
391

    
392
--
393
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
394
--
395

    
396
CREATE VIEW "MatchedTaxon" AS
397
 SELECT taxon_best_match.batch,
398
    taxon_best_match.match_num,
399
    taxon_best_match."Name_number",
400
    taxon_best_match."Name_submitted",
401
    taxon_best_match."Overall_score",
402
    taxon_best_match."Name_matched",
403
    taxon_best_match."Name_matched_rank",
404
    taxon_best_match."Name_score",
405
    taxon_best_match."Name_matched_author",
406
    taxon_best_match."Name_matched_url",
407
    taxon_best_match."Author_matched",
408
    taxon_best_match."Author_score",
409
    taxon_best_match."Family_matched",
410
    taxon_best_match."Family_score",
411
    taxon_best_match."Name_matched_accepted_family",
412
    taxon_best_match."Genus_matched",
413
    taxon_best_match."Genus_score",
414
    taxon_best_match."Specific_epithet_matched",
415
    taxon_best_match."Specific_epithet_score",
416
    taxon_best_match."Infraspecific_rank",
417
    taxon_best_match."Infraspecific_epithet_matched",
418
    taxon_best_match."Infraspecific_epithet_score",
419
    taxon_best_match."Infraspecific_rank_2",
420
    taxon_best_match."Infraspecific_epithet_2_matched",
421
    taxon_best_match."Infraspecific_epithet_2_score",
422
    taxon_best_match."Annotations",
423
    taxon_best_match."Unmatched_terms",
424
    taxon_best_match."Taxonomic_status",
425
    taxon_best_match."Accepted_name",
426
    taxon_best_match."Accepted_name_author",
427
    taxon_best_match."Accepted_name_rank",
428
    taxon_best_match."Accepted_name_url",
429
    taxon_best_match."Accepted_name_species",
430
    taxon_best_match."Accepted_name_family",
431
    taxon_best_match."Selected",
432
    taxon_best_match."Source",
433
    taxon_best_match."Warnings",
434
    taxon_best_match."Accepted_name_lsid",
435
    taxon_best_match.is_valid_match,
436
    taxon_best_match.scrubbed_unique_taxon_name,
437
    map_taxonomic_status(taxon_best_match."Taxonomic_status", taxon_best_match."Accepted_name") AS "taxonomicStatus",
438
        CASE
439
            WHEN (taxon_best_match."Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."Accepted_name_family", taxon_best_match."Unmatched_terms")
440
            WHEN (taxon_best_match."Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."Accepted_name", taxon_best_match."Unmatched_terms")
441
            ELSE taxon_best_match."Accepted_name_species"
442
        END AS accepted_morphospecies_binomial
443
   FROM taxon_best_match;
444

    
445

    
446
--
447
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
448
--
449

    
450
COMMENT ON VIEW "MatchedTaxon" IS '
451
to modify:
452
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
453
SELECT __
454
$$);
455
';
456

    
457

    
458
--
459
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
460
--
461

    
462
CREATE VIEW "ValidMatchedTaxon" AS
463
 SELECT "MatchedTaxon".batch,
464
    "MatchedTaxon".match_num,
465
    "MatchedTaxon"."Name_number",
466
    "MatchedTaxon"."Name_submitted",
467
    "MatchedTaxon"."Overall_score",
468
    "MatchedTaxon"."Name_matched",
469
    "MatchedTaxon"."Name_matched_rank",
470
    "MatchedTaxon"."Name_score",
471
    "MatchedTaxon"."Name_matched_author",
472
    "MatchedTaxon"."Name_matched_url",
473
    "MatchedTaxon"."Author_matched",
474
    "MatchedTaxon"."Author_score",
475
    "MatchedTaxon"."Family_matched",
476
    "MatchedTaxon"."Family_score",
477
    "MatchedTaxon"."Name_matched_accepted_family",
478
    "MatchedTaxon"."Genus_matched",
479
    "MatchedTaxon"."Genus_score",
480
    "MatchedTaxon"."Specific_epithet_matched",
481
    "MatchedTaxon"."Specific_epithet_score",
482
    "MatchedTaxon"."Infraspecific_rank",
483
    "MatchedTaxon"."Infraspecific_epithet_matched",
484
    "MatchedTaxon"."Infraspecific_epithet_score",
485
    "MatchedTaxon"."Infraspecific_rank_2",
486
    "MatchedTaxon"."Infraspecific_epithet_2_matched",
487
    "MatchedTaxon"."Infraspecific_epithet_2_score",
488
    "MatchedTaxon"."Annotations",
489
    "MatchedTaxon"."Unmatched_terms",
490
    "MatchedTaxon"."Taxonomic_status",
491
    "MatchedTaxon"."Accepted_name",
492
    "MatchedTaxon"."Accepted_name_author",
493
    "MatchedTaxon"."Accepted_name_rank",
494
    "MatchedTaxon"."Accepted_name_url",
495
    "MatchedTaxon"."Accepted_name_species",
496
    "MatchedTaxon"."Accepted_name_family",
497
    "MatchedTaxon"."Selected",
498
    "MatchedTaxon"."Source",
499
    "MatchedTaxon"."Warnings",
500
    "MatchedTaxon"."Accepted_name_lsid",
501
    "MatchedTaxon".is_valid_match,
502
    "MatchedTaxon".scrubbed_unique_taxon_name,
503
    "MatchedTaxon"."taxonomicStatus",
504
    "MatchedTaxon".accepted_morphospecies_binomial
505
   FROM "MatchedTaxon"
506
  WHERE "MatchedTaxon".is_valid_match;
507

    
508

    
509
--
510
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
511
--
512

    
513
COMMENT ON VIEW "ValidMatchedTaxon" IS '
514
to update, use * as the column list
515
';
516

    
517

    
518
--
519
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
520
--
521

    
522
CREATE TABLE batch (
523
    id text NOT NULL,
524
    id_by_time text,
525
    time_submitted timestamp with time zone DEFAULT now(),
526
    client_version text
527
);
528

    
529

    
530
--
531
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
532
--
533

    
534
CREATE TABLE batch_download_settings (
535
    id text NOT NULL,
536
    "E-mail" text,
537
    "Id" text,
538
    "Job type" text,
539
    "Contains Id" boolean,
540
    "Start time" text,
541
    "Finish time" text,
542
    "TNRS version" text,
543
    "Sources selected" text,
544
    "Match threshold" double precision,
545
    "Classification" text,
546
    "Allow partial matches?" boolean,
547
    "Sort by source" boolean,
548
    "Constrain by higher taxonomy" boolean
549
);
550

    
551

    
552
--
553
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
554
--
555

    
556
COMMENT ON TABLE batch_download_settings IS '
557
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
558
';
559

    
560

    
561
--
562
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
563
--
564

    
565
CREATE TABLE client_version (
566
    id text NOT NULL,
567
    global_rev integer NOT NULL,
568
    "/lib/tnrs.py rev" integer,
569
    "/bin/tnrs_db rev" integer
570
);
571

    
572

    
573
--
574
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
575
--
576

    
577
COMMENT ON TABLE client_version IS '
578
contains svn revisions
579
';
580

    
581

    
582
--
583
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
584
--
585

    
586
COMMENT ON COLUMN client_version.global_rev IS '
587
from `svn info .` > Last Changed Rev
588
';
589

    
590

    
591
--
592
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
593
--
594

    
595
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
596
from `svn info lib/tnrs.py` > Last Changed Rev
597
';
598

    
599

    
600
--
601
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
602
--
603

    
604
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
605
from `svn info bin/tnrs_db` > Last Changed Rev
606
';
607

    
608

    
609
--
610
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
611
--
612

    
613
CREATE VIEW taxon_match_input AS
614
 SELECT taxon_match."Name_number",
615
    taxon_match."Name_submitted",
616
    taxon_match."Overall_score",
617
    taxon_match."Name_matched",
618
    taxon_match."Name_matched_rank",
619
    taxon_match."Name_score",
620
    taxon_match."Name_matched_author",
621
    taxon_match."Name_matched_url",
622
    taxon_match."Author_matched",
623
    taxon_match."Author_score",
624
    taxon_match."Family_matched",
625
    taxon_match."Family_score",
626
    taxon_match."Name_matched_accepted_family",
627
    taxon_match."Genus_matched",
628
    taxon_match."Genus_score",
629
    taxon_match."Specific_epithet_matched",
630
    taxon_match."Specific_epithet_score",
631
    taxon_match."Infraspecific_rank",
632
    taxon_match."Infraspecific_epithet_matched",
633
    taxon_match."Infraspecific_epithet_score",
634
    taxon_match."Infraspecific_rank_2",
635
    taxon_match."Infraspecific_epithet_2_matched",
636
    taxon_match."Infraspecific_epithet_2_score",
637
    taxon_match."Annotations",
638
    taxon_match."Unmatched_terms",
639
    taxon_match."Taxonomic_status",
640
    taxon_match."Accepted_name",
641
    taxon_match."Accepted_name_author",
642
    taxon_match."Accepted_name_rank",
643
    taxon_match."Accepted_name_url",
644
    taxon_match."Accepted_name_species",
645
    taxon_match."Accepted_name_family",
646
    taxon_match."Selected",
647
    taxon_match."Source",
648
    taxon_match."Warnings",
649
    taxon_match."Accepted_name_lsid"
650
   FROM taxon_match;
651

    
652

    
653
--
654
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
655
--
656

    
657
CREATE TABLE taxon_match_input__copy_to (
658
    "Name_number" integer,
659
    "Name_submitted" text,
660
    "Overall_score" double precision,
661
    "Name_matched" text,
662
    "Name_matched_rank" text,
663
    "Name_score" double precision,
664
    "Name_matched_author" text,
665
    "Name_matched_url" text,
666
    "Author_matched" text,
667
    "Author_score" double precision,
668
    "Family_matched" text,
669
    "Family_score" double precision,
670
    "Name_matched_accepted_family" text,
671
    "Genus_matched" text,
672
    "Genus_score" double precision,
673
    "Specific_epithet_matched" text,
674
    "Specific_epithet_score" double precision,
675
    "Infraspecific_rank" text,
676
    "Infraspecific_epithet_matched" text,
677
    "Infraspecific_epithet_score" double precision,
678
    "Infraspecific_rank_2" text,
679
    "Infraspecific_epithet_2_matched" text,
680
    "Infraspecific_epithet_2_score" double precision,
681
    "Annotations" text,
682
    "Unmatched_terms" text,
683
    "Taxonomic_status" text,
684
    "Accepted_name" text,
685
    "Accepted_name_author" text,
686
    "Accepted_name_rank" text,
687
    "Accepted_name_url" text,
688
    "Accepted_name_species" text,
689
    "Accepted_name_family" text,
690
    "Selected" text,
691
    "Source" text,
692
    "Warnings" text,
693
    "Accepted_name_lsid" text
694
);
695

    
696

    
697
--
698
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
699
--
700

    
701
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
702
 SELECT taxon_match."Name_submitted" AS scrubbed_unique_taxon_name,
703
    taxon_match."Name_matched_rank" AS scrubbed_taxon_rank,
704
    COALESCE(taxon_match."Name_matched_accepted_family", taxon_match."Family_matched") AS scrubbed_family,
705
    taxon_match."Genus_matched" AS scrubbed_genus,
706
    taxon_match."Specific_epithet_matched" AS scrubbed_specific_epithet,
707
    taxon_match."Infraspecific_rank" AS scrubbed_infraspecific_rank,
708
    taxon_match."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
709
    taxon_match."Name_matched_author" AS scrubbed_author,
710
    taxon_match."Name_matched" AS scrubbed_taxon_name_no_author,
711
    (taxon_match."Name_matched" || COALESCE((' '::text || taxon_match."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
712
   FROM taxon_match;
713

    
714

    
715
--
716
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
717
--
718

    
719
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
720
to modify:
721
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
722
SELECT __
723
$$);
724

    
725
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.
726
';
727

    
728

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

    
733
CREATE VIEW taxon_scrub AS
734
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
735
    "ValidMatchedTaxon".batch,
736
    "ValidMatchedTaxon".match_num,
737
    "ValidMatchedTaxon"."Name_number",
738
    "ValidMatchedTaxon"."Name_submitted",
739
    "ValidMatchedTaxon"."Overall_score",
740
    "ValidMatchedTaxon"."Name_matched",
741
    "ValidMatchedTaxon"."Name_matched_rank",
742
    "ValidMatchedTaxon"."Name_score",
743
    "ValidMatchedTaxon"."Name_matched_author",
744
    "ValidMatchedTaxon"."Name_matched_url",
745
    "ValidMatchedTaxon"."Author_matched",
746
    "ValidMatchedTaxon"."Author_score",
747
    "ValidMatchedTaxon"."Family_matched",
748
    "ValidMatchedTaxon"."Family_score",
749
    "ValidMatchedTaxon"."Name_matched_accepted_family",
750
    "ValidMatchedTaxon"."Genus_matched",
751
    "ValidMatchedTaxon"."Genus_score",
752
    "ValidMatchedTaxon"."Specific_epithet_matched",
753
    "ValidMatchedTaxon"."Specific_epithet_score",
754
    "ValidMatchedTaxon"."Infraspecific_rank",
755
    "ValidMatchedTaxon"."Infraspecific_epithet_matched",
756
    "ValidMatchedTaxon"."Infraspecific_epithet_score",
757
    "ValidMatchedTaxon"."Infraspecific_rank_2",
758
    "ValidMatchedTaxon"."Infraspecific_epithet_2_matched",
759
    "ValidMatchedTaxon"."Infraspecific_epithet_2_score",
760
    "ValidMatchedTaxon"."Annotations",
761
    "ValidMatchedTaxon"."Unmatched_terms",
762
    "ValidMatchedTaxon"."Taxonomic_status",
763
    "ValidMatchedTaxon"."Accepted_name",
764
    "ValidMatchedTaxon"."Accepted_name_author",
765
    "ValidMatchedTaxon"."Accepted_name_rank",
766
    "ValidMatchedTaxon"."Accepted_name_url",
767
    "ValidMatchedTaxon"."Accepted_name_species",
768
    "ValidMatchedTaxon"."Accepted_name_family",
769
    "ValidMatchedTaxon"."Selected",
770
    "ValidMatchedTaxon"."Source",
771
    "ValidMatchedTaxon"."Warnings",
772
    "ValidMatchedTaxon"."Accepted_name_lsid",
773
    "ValidMatchedTaxon".is_valid_match,
774
    "ValidMatchedTaxon"."taxonomicStatus",
775
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
776
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
777
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
778
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
779
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
780
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
781
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
782
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
783
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
784
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
785
        CASE
786
            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"."Unmatched_terms")
787
            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"."Unmatched_terms")
788
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
789
        END AS scrubbed_morphospecies_binomial
790
   FROM ("ValidMatchedTaxon"
791
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
792

    
793

    
794
--
795
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
796
--
797

    
798
COMMENT ON VIEW taxon_scrub IS '
799
to modify:
800
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
801
SELECT __
802
$$);
803
';
804

    
805

    
806
--
807
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
808
--
809

    
810
ALTER TABLE ONLY batch_download_settings
811
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
812

    
813

    
814
--
815
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
816
--
817

    
818
ALTER TABLE ONLY batch
819
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
820

    
821

    
822
--
823
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
824
--
825

    
826
ALTER TABLE ONLY batch
827
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
828

    
829

    
830
--
831
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
832
--
833

    
834
ALTER TABLE ONLY client_version
835
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
836

    
837

    
838
--
839
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
840
--
841

    
842
ALTER TABLE ONLY taxon_match
843
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
844

    
845

    
846
--
847
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
848
--
849

    
850
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
851

    
852

    
853
--
854
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
855
--
856

    
857
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("Name_submitted") WHERE (("Selected" = 'true'::text) AND is_valid_match);
858

    
859

    
860
--
861
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
862
--
863

    
864
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("Name_submitted");
865

    
866

    
867
--
868
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
869
--
870

    
871
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "Name_number") WHERE ("Selected" = 'true'::text);
872

    
873

    
874
--
875
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
876
--
877

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

    
880

    
881
--
882
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
883
--
884

    
885
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
886

    
887

    
888
--
889
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
890
--
891

    
892
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
893

    
894

    
895
--
896
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
897
--
898

    
899
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
900

    
901

    
902
--
903
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
904
--
905

    
906
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();
907

    
908

    
909
--
910
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
911
--
912

    
913
ALTER TABLE ONLY batch
914
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
915

    
916

    
917
--
918
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
919
--
920

    
921
ALTER TABLE ONLY batch_download_settings
922
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
923

    
924

    
925
--
926
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
927
--
928

    
929
ALTER TABLE ONLY taxon_match
930
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
931

    
932

    
933
--
934
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
935
--
936

    
937
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
938
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
939
GRANT ALL ON SCHEMA "TNRS" TO bien;
940
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
941

    
942

    
943
--
944
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
945
--
946

    
947
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
948
REVOKE ALL ON TABLE taxon_match FROM bien;
949
GRANT ALL ON TABLE taxon_match TO bien;
950
GRANT SELECT ON TABLE taxon_match TO bien_read;
951

    
952

    
953
--
954
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
955
--
956

    
957
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
958
REVOKE ALL ON TABLE taxon_best_match FROM bien;
959
GRANT ALL ON TABLE taxon_best_match TO bien;
960
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
961

    
962

    
963
--
964
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
965
--
966

    
967
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
968
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
969
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
970
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
971

    
972

    
973
--
974
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
975
--
976

    
977
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
978
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
979
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
980
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
981

    
982

    
983
--
984
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
985
--
986

    
987
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
988
REVOKE ALL ON TABLE taxon_match_input FROM bien;
989
GRANT ALL ON TABLE taxon_match_input TO bien;
990
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
991

    
992

    
993
--
994
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
995
--
996

    
997
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
998
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
999
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1000
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1001

    
1002

    
1003
--
1004
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1005
--
1006

    
1007
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1008
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1009
GRANT ALL ON TABLE taxon_scrub TO bien;
1010
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1011

    
1012

    
1013
--
1014
-- PostgreSQL database dump complete
1015
--
1016

    
(7-7/9)