Project

General

Profile

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

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

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

    
16
--CREATE SCHEMA "TNRS";
17

    
18

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

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

    
41

    
42
SET search_path = "TNRS", pg_catalog;
43

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

    
48
CREATE FUNCTION "MatchedTaxon_modify"(view_query text) RETURNS void
49
    LANGUAGE sql
50
    AS $_$
51
SELECT util.recreate_view('"TNRS"."MatchedTaxon"', $1, $$
52
-- **IMPORTANT**: keep these updated as described in the views' comments
53

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

    
60
CREATE VIEW "TNRS".taxon_scrub AS 
61
 SELECT *
62
   FROM "TNRS"."ValidMatchedTaxon"
63
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
64
$$||util.mk_set_relation_metadata('"TNRS".taxon_scrub')||$$
65
$$);
66
$_$;
67

    
68

    
69
--
70
-- Name: FUNCTION "MatchedTaxon_modify"(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
71
--
72

    
73
COMMENT ON FUNCTION "MatchedTaxon_modify"(view_query text) IS '
74
usage:
75
SELECT "TNRS"."MatchedTaxon_modify"($$
76
 SELECT *, __ AS accepted_morphospecies_binomial
77
   FROM __
78
$$);
79

    
80
idempotent
81
';
82

    
83

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

    
88
CREATE FUNCTION batch__fill() RETURNS trigger
89
    LANGUAGE plpgsql
90
    AS $$
91
BEGIN
92
	new.id_by_time = new.time_submitted;
93
	new.id = COALESCE(new.id, new.id_by_time);
94
	RETURN new;
95
END;
96
$$;
97

    
98

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

    
103
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
104
    LANGUAGE sql STABLE STRICT
105
    AS $_$
106
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
107
$_$;
108

    
109

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

    
114
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
115
    LANGUAGE sql STABLE STRICT
116
    AS $_$
117
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
118
$_$;
119

    
120

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

    
125
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
126
    LANGUAGE sql IMMUTABLE
127
    AS $_$
128
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
129
"taxonomic_status should be accepted instead of synonym when an accepted name is
130
available (this is not always the case when a name is marked as a synonym)" */
131
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
132
$_$;
133

    
134

    
135
--
136
-- Name: taxon_scrub_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
137
--
138

    
139
CREATE FUNCTION taxon_scrub_modify(view_query text) RETURNS void
140
    LANGUAGE sql
141
    AS $_$
142
SELECT util.recreate_view('"TNRS".taxon_scrub', $1);
143
$_$;
144

    
145

    
146
--
147
-- Name: FUNCTION taxon_scrub_modify(view_query text); Type: COMMENT; Schema: TNRS; Owner: -
148
--
149

    
150
COMMENT ON FUNCTION taxon_scrub_modify(view_query text) IS '
151
usage:
152
SELECT "TNRS".taxon_scrub_modify($$
153
 SELECT *, __ AS scrubbed_morphospecies_binomial
154
   FROM "TNRS"."ValidMatchedTaxon"
155
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
156
$$);
157

    
158
idempotent
159
';
160

    
161

    
162
--
163
-- Name: tnrs__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
164
--
165

    
166
CREATE FUNCTION tnrs__batch_begin() RETURNS trigger
167
    LANGUAGE plpgsql
168
    AS $$
169
BEGIN
170
	PERFORM util.seq__reset('pg_temp.tnrs__match_num__seq', 0);
171
	RETURN NULL;
172
END;
173
$$;
174

    
175

    
176
--
177
-- Name: tnrs__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
178
--
179

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

    
189

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

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

    
200

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

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

    
262

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

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

    
275

    
276
SET default_tablespace = '';
277

    
278
SET default_with_oids = false;
279

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

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

    
327

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

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

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

    
342
to populate a new column:
343
ALTER TABLE "TNRS".tnrs DISABLE TRIGGER tnrs_populate_fields; --speeds up update
344
UPDATE "TNRS".tnrs SET "col" = value;
345
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
346
ALTER TABLE "TNRS".tnrs ENABLE TRIGGER tnrs_populate_fields;
347
VACUUM ANALYZE "TNRS".tnrs --remove previous rows; runtime: 1.5 min ("92633 ms")
348
';
349

    
350

    
351
--
352
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
353
--
354

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

    
425

    
426
--
427
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
428
--
429

    
430
COMMENT ON VIEW "MatchedTaxon" IS '
431
to modify:
432
SELECT "TNRS"."MatchedTaxon_modify"($$
433
 SELECT *, __ AS accepted_morphospecies_binomial
434
   FROM __
435
$$);
436
';
437

    
438

    
439
--
440
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
441
--
442

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

    
479

    
480
--
481
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
482
--
483

    
484
COMMENT ON VIEW "ValidMatchedTaxon" IS '
485
to update, use * as the column list
486
';
487

    
488

    
489
--
490
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
491
--
492

    
493
CREATE TABLE batch (
494
    id text NOT NULL,
495
    id_by_time text,
496
    time_submitted timestamp with time zone DEFAULT now(),
497
    client_version text
498
);
499

    
500

    
501
--
502
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
503
--
504

    
505
CREATE TABLE batch_download_settings (
506
    id text NOT NULL,
507
    "E-mail" text,
508
    "Id" text,
509
    "Job type" text,
510
    "Contains Id" boolean,
511
    "Start time" text,
512
    "Finish time" text,
513
    "TNRS version" text,
514
    "Sources selected" text,
515
    "Match threshold" double precision,
516
    "Classification" text,
517
    "Allow partial matches?" boolean,
518
    "Sort by source" boolean,
519
    "Constrain by higher taxonomy" boolean
520
);
521

    
522

    
523
--
524
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
525
--
526

    
527
COMMENT ON TABLE batch_download_settings IS '
528
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
529
';
530

    
531

    
532
--
533
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
534
--
535

    
536
CREATE TABLE client_version (
537
    id text NOT NULL,
538
    global_rev integer NOT NULL,
539
    "/lib/tnrs.py rev" integer,
540
    "/bin/tnrs_db rev" integer
541
);
542

    
543

    
544
--
545
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
546
--
547

    
548
COMMENT ON TABLE client_version IS '
549
contains svn revisions
550
';
551

    
552

    
553
--
554
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
555
--
556

    
557
COMMENT ON COLUMN client_version.global_rev IS '
558
from `svn info .` > Last Changed Rev
559
';
560

    
561

    
562
--
563
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
564
--
565

    
566
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
567
from `svn info lib/tnrs.py` > Last Changed Rev
568
';
569

    
570

    
571
--
572
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
573
--
574

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

    
579

    
580
--
581
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
582
--
583

    
584
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
585
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
586
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
587
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
588
    tnrs."Genus_matched" AS scrubbed_genus, 
589
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
590
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
591
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
592
    tnrs."Name_matched_author" AS scrubbed_author, 
593
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
594
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
595
   FROM tnrs;
596

    
597

    
598
--
599
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
600
--
601

    
602
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
603
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.
604
';
605

    
606

    
607
--
608
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
609
--
610

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

    
661

    
662
--
663
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
664
--
665

    
666
COMMENT ON VIEW taxon_scrub IS '
667
to modify:
668
SELECT "TNRS".taxon_scrub_modify($$
669
 SELECT *, __ AS scrubbed_morphospecies_binomial
670
   FROM "TNRS"."ValidMatchedTaxon"
671
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
672
$$);
673
';
674

    
675

    
676
--
677
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
678
--
679

    
680
ALTER TABLE ONLY batch_download_settings
681
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
682

    
683

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

    
688
ALTER TABLE ONLY batch
689
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
690

    
691

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

    
696
ALTER TABLE ONLY batch
697
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
698

    
699

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

    
704
ALTER TABLE ONLY client_version
705
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
706

    
707

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

    
712
ALTER TABLE ONLY tnrs
713
    ADD CONSTRAINT "tnrs_Name_submitted_Name_matched_key" UNIQUE ("Name_submitted", "Name_matched");
714

    
715

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

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

    
723

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

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

    
730

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

    
735
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
736

    
737

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

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

    
744

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

    
749
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
750

    
751

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

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

    
758

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

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

    
765

    
766
--
767
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
768
--
769

    
770
ALTER TABLE ONLY batch
771
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
772

    
773

    
774
--
775
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
776
--
777

    
778
ALTER TABLE ONLY batch_download_settings
779
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
780

    
781

    
782
--
783
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
784
--
785

    
786
ALTER TABLE ONLY tnrs
787
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
788

    
789

    
790
--
791
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
792
--
793

    
794
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
795
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
796
GRANT ALL ON SCHEMA "TNRS" TO bien;
797
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
798

    
799

    
800
--
801
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
802
--
803

    
804
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
805
REVOKE ALL ON TABLE tnrs FROM bien;
806
GRANT ALL ON TABLE tnrs TO bien;
807
GRANT SELECT ON TABLE tnrs TO bien_read;
808

    
809

    
810
--
811
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
812
--
813

    
814
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
815
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
816
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
817
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
818

    
819

    
820
--
821
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
822
--
823

    
824
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
825
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
826
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
827
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
828

    
829

    
830
--
831
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
832
--
833

    
834
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
835
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
836
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
837
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
838

    
839

    
840
--
841
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
842
--
843

    
844
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
845
REVOKE ALL ON TABLE taxon_scrub FROM bien;
846
GRANT ALL ON TABLE taxon_scrub TO bien;
847
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
848

    
849

    
850
--
851
-- PostgreSQL database dump complete
852
--
853

    
(8-8/10)