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

    
39

    
40
SET search_path = "TNRS", pg_catalog;
41

    
42
--
43
-- Name: MatchedTaxon_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
44
--
45

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

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

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

    
66

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

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

    
78
idempotent
79
';
80

    
81

    
82
--
83
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
84
--
85

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

    
96

    
97
--
98
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
99
--
100

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

    
107

    
108
--
109
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
110
--
111

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

    
118

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

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

    
132

    
133
--
134
-- Name: taxon_scrub_modify(text); Type: FUNCTION; Schema: TNRS; Owner: -
135
--
136

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

    
143

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

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

    
156
idempotent
157
';
158

    
159

    
160
--
161
-- Name: tnrs__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
162
--
163

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

    
173

    
174
--
175
-- Name: tnrs__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
176
--
177

    
178
CREATE FUNCTION tnrs__match_num__next() RETURNS bigint
179
    LANGUAGE sql
180
    AS $$
181
SELECT nextval('pg_temp.tnrs__match_num__seq');
182
$$;
183

    
184

    
185
--
186
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
187
--
188

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

    
246

    
247
--
248
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
249
--
250

    
251
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
252
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
253
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
254
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
255
runtime: 1.5 min ("92633 ms")';
256

    
257

    
258
SET default_tablespace = '';
259

    
260
SET default_with_oids = false;
261

    
262
--
263
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
264
--
265

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

    
309

    
310
--
311
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
312
--
313

    
314
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
315
$ inputs/.TNRS/data.sql.run refresh';
316

    
317

    
318
--
319
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
320
--
321

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

    
392

    
393
--
394
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
395
--
396

    
397
COMMENT ON VIEW "MatchedTaxon" IS '
398
to modify:
399
SELECT "TNRS"."MatchedTaxon_modify"($$
400
 SELECT *, __ AS accepted_morphospecies_binomial
401
   FROM __
402
$$);
403
';
404

    
405

    
406
--
407
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
408
--
409

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

    
446

    
447
--
448
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
449
--
450

    
451
COMMENT ON VIEW "ValidMatchedTaxon" IS '
452
to update, use * as the column list
453
';
454

    
455

    
456
--
457
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
458
--
459

    
460
CREATE TABLE batch (
461
    id text NOT NULL,
462
    id_by_time text,
463
    time_submitted timestamp with time zone DEFAULT now(),
464
    client_version text
465
);
466

    
467

    
468
--
469
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
470
--
471

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

    
489

    
490
--
491
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
492
--
493

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

    
496

    
497
--
498
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
499
--
500

    
501
CREATE TABLE client_version (
502
    id text NOT NULL,
503
    global_rev integer NOT NULL,
504
    "/lib/tnrs.py rev" integer,
505
    "/bin/tnrs_db rev" integer
506
);
507

    
508

    
509
--
510
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
511
--
512

    
513
COMMENT ON TABLE client_version IS 'contains svn revisions';
514

    
515

    
516
--
517
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
518
--
519

    
520
COMMENT ON COLUMN client_version.global_rev IS 'from `svn info .` > Last Changed Rev';
521

    
522

    
523
--
524
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
525
--
526

    
527
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS 'from `svn info lib/tnrs.py` > Last Changed Rev';
528

    
529

    
530
--
531
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
532
--
533

    
534
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS 'from `svn info bin/tnrs_db` > Last Changed Rev';
535

    
536

    
537
--
538
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
539
--
540

    
541
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
542
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
543
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
544
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
545
    tnrs."Genus_matched" AS scrubbed_genus, 
546
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
547
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
548
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
549
    tnrs."Name_matched_author" AS scrubbed_author, 
550
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
551
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
552
   FROM tnrs;
553

    
554

    
555
--
556
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
557
--
558

    
559
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '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.';
560

    
561

    
562
--
563
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
564
--
565

    
566
CREATE VIEW taxon_scrub AS
567
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
568
    "ValidMatchedTaxon"."*Name_matched.batch", 
569
    "ValidMatchedTaxon"."concatenatedScientificName", 
570
    "ValidMatchedTaxon"."matchedTaxonName", 
571
    "ValidMatchedTaxon"."matchedTaxonRank", 
572
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
573
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
574
    "ValidMatchedTaxon"."matchedScientificNameID", 
575
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
576
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
577
    "ValidMatchedTaxon"."matchedFamily", 
578
    "ValidMatchedTaxon"."matchedGenus", 
579
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
580
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
581
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
582
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
583
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
584
    "ValidMatchedTaxon"."identificationQualifier", 
585
    "ValidMatchedTaxon"."morphospeciesSuffix", 
586
    "ValidMatchedTaxon"."taxonomicStatus", 
587
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
588
    "ValidMatchedTaxon".accepted_author, 
589
    "ValidMatchedTaxon".accepted_taxon_rank, 
590
    "ValidMatchedTaxon"."acceptedScientificNameID", 
591
    "ValidMatchedTaxon".accepted_species_binomial, 
592
    "ValidMatchedTaxon".accepted_family, 
593
    "ValidMatchedTaxon"."*Name_matched.Selected", 
594
    "ValidMatchedTaxon"."*Name_matched.Source", 
595
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
596
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
597
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
598
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
599
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
600
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
601
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
602
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
603
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
604
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
605
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
606
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, 
607
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author, 
608
        CASE
609
            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")
610
            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")
611
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
612
        END AS scrubbed_morphospecies_binomial
613
   FROM ("ValidMatchedTaxon"
614
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
615

    
616

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

    
621
COMMENT ON VIEW taxon_scrub IS '
622
to modify:
623
SELECT "TNRS".taxon_scrub_modify($$
624
 SELECT *, __ AS scrubbed_morphospecies_binomial
625
   FROM "TNRS"."ValidMatchedTaxon"
626
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
627
$$);
628
';
629

    
630

    
631
--
632
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
633
--
634

    
635
ALTER TABLE ONLY batch_download_settings
636
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
637

    
638

    
639
--
640
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
641
--
642

    
643
ALTER TABLE ONLY batch
644
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
645

    
646

    
647
--
648
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
649
--
650

    
651
ALTER TABLE ONLY batch
652
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
653

    
654

    
655
--
656
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
657
--
658

    
659
ALTER TABLE ONLY client_version
660
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
661

    
662

    
663
--
664
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
665
--
666

    
667
ALTER TABLE ONLY tnrs
668
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
669

    
670

    
671
--
672
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
673
--
674

    
675
ALTER TABLE ONLY tnrs
676
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
677

    
678

    
679
--
680
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
681
--
682

    
683
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
684

    
685

    
686
--
687
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
688
--
689

    
690
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
691

    
692

    
693
--
694
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
695
--
696

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

    
699

    
700
--
701
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
702
--
703

    
704
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
705

    
706

    
707
--
708
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
709
--
710

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

    
713

    
714
--
715
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
716
--
717

    
718
ALTER TABLE ONLY batch
719
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
720

    
721

    
722
--
723
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
724
--
725

    
726
ALTER TABLE ONLY batch_download_settings
727
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
728

    
729

    
730
--
731
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
732
--
733

    
734
ALTER TABLE ONLY tnrs
735
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
736

    
737

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

    
742
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
743
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
744
GRANT ALL ON SCHEMA "TNRS" TO bien;
745
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
746

    
747

    
748
--
749
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
750
--
751

    
752
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
753
REVOKE ALL ON TABLE tnrs FROM bien;
754
GRANT ALL ON TABLE tnrs TO bien;
755
GRANT SELECT ON TABLE tnrs TO bien_read;
756

    
757

    
758
--
759
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
760
--
761

    
762
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
763
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
764
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
765
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
766

    
767

    
768
--
769
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
770
--
771

    
772
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
773
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
774
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
775
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
776

    
777

    
778
--
779
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
780
--
781

    
782
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
783
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
784
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
785
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
786

    
787

    
788
--
789
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
790
--
791

    
792
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
793
REVOKE ALL ON TABLE taxon_scrub FROM bien;
794
GRANT ALL ON TABLE taxon_scrub TO bien;
795
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
796

    
797

    
798
--
799
-- PostgreSQL database dump complete
800
--
801

    
(8-8/10)