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

    
308

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

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

    
316

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

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

    
391

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

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

    
404

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

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

    
445

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

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

    
454

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

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

    
466

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

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

    
488

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

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

    
495

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

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

    
507

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

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

    
514

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

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

    
521

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

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

    
528

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

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

    
535

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

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

    
553

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

    
558
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.';
559

    
560

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

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

    
615

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

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

    
629

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

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

    
637

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

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

    
645

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

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

    
653

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

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

    
661

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

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

    
669

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

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

    
677

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

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

    
684

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

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

    
691

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

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

    
698

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

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

    
705

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

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

    
712

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

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

    
720

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

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

    
728

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

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

    
736

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

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

    
746

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

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

    
756

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

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

    
766

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

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

    
776

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

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

    
786

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

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

    
796

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

    
(8-8/10)