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_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
176
--
177

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

    
235

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

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

    
246

    
247
SET default_tablespace = '';
248

    
249
SET default_with_oids = false;
250

    
251
--
252
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
253
--
254

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

    
297

    
298
--
299
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
300
--
301

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

    
305

    
306
--
307
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
308
--
309

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

    
380

    
381
--
382
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
383
--
384

    
385
COMMENT ON VIEW "MatchedTaxon" IS '
386
to modify:
387
SELECT "TNRS"."MatchedTaxon_modify"($$
388
 SELECT *, __ AS accepted_morphospecies_binomial
389
   FROM __
390
$$);
391
';
392

    
393

    
394
--
395
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
396
--
397

    
398
CREATE VIEW "ValidMatchedTaxon" AS
399
 SELECT "MatchedTaxon"."*Name_matched.batch", 
400
    "MatchedTaxon"."concatenatedScientificName", 
401
    "MatchedTaxon"."matchedTaxonName", 
402
    "MatchedTaxon"."matchedTaxonRank", 
403
    "MatchedTaxon"."*Name_matched.Name_score", 
404
    "MatchedTaxon"."matchedScientificNameAuthorship", 
405
    "MatchedTaxon"."matchedScientificNameID", 
406
    "MatchedTaxon"."*Name_matched.Author_score", 
407
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
408
    "MatchedTaxon"."matchedFamily", 
409
    "MatchedTaxon"."matchedGenus", 
410
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
411
    "MatchedTaxon"."matchedSpecificEpithet", 
412
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
413
    "MatchedTaxon"."matchedInfraspecificEpithet", 
414
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
415
    "MatchedTaxon"."identificationQualifier", 
416
    "MatchedTaxon"."morphospeciesSuffix", 
417
    "MatchedTaxon"."taxonomicStatus", 
418
    "MatchedTaxon".accepted_taxon_name_no_author, 
419
    "MatchedTaxon".accepted_author, 
420
    "MatchedTaxon".accepted_taxon_rank, 
421
    "MatchedTaxon"."acceptedScientificNameID", 
422
    "MatchedTaxon".accepted_species_binomial, 
423
    "MatchedTaxon".accepted_family, 
424
    "MatchedTaxon"."*Name_matched.Selected", 
425
    "MatchedTaxon"."*Name_matched.Source", 
426
    "MatchedTaxon"."*Name_matched.Warnings", 
427
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
428
    "MatchedTaxon".taxon_scrub__is_valid_match, 
429
    "MatchedTaxon".scrubbed_unique_taxon_name, 
430
    "MatchedTaxon".accepted_morphospecies_binomial
431
   FROM "MatchedTaxon"
432
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
433

    
434

    
435
--
436
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
437
--
438

    
439
COMMENT ON VIEW "ValidMatchedTaxon" IS '
440
to update, use * as the column list
441
';
442

    
443

    
444
--
445
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
446
--
447

    
448
CREATE TABLE batch (
449
    id text NOT NULL,
450
    id_by_time text,
451
    time_submitted timestamp with time zone DEFAULT now(),
452
    client_version text
453
);
454

    
455

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

    
460
CREATE TABLE batch_download_settings (
461
    id text NOT NULL,
462
    "E-mail" text,
463
    "Id" text,
464
    "Job type" text,
465
    "Contains Id" boolean,
466
    "Start time" text,
467
    "Finish time" text,
468
    "TNRS version" text,
469
    "Sources selected" text,
470
    "Match threshold" double precision,
471
    "Classification" text,
472
    "Allow partial matches?" boolean,
473
    "Sort by source" boolean,
474
    "Constrain by higher taxonomy" boolean
475
);
476

    
477

    
478
--
479
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
480
--
481

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

    
484

    
485
--
486
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
487
--
488

    
489
CREATE TABLE client_version (
490
    id text NOT NULL,
491
    global_rev integer NOT NULL,
492
    "/lib/tnrs.py rev" integer,
493
    "/bin/tnrs_db rev" integer
494
);
495

    
496

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

    
501
COMMENT ON TABLE client_version IS 'contains svn revisions';
502

    
503

    
504
--
505
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
506
--
507

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

    
510

    
511
--
512
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
513
--
514

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

    
517

    
518
--
519
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
520
--
521

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

    
524

    
525
--
526
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
527
--
528

    
529
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
530
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
531
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
532
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
533
    tnrs."Genus_matched" AS scrubbed_genus, 
534
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
535
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
536
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
537
    tnrs."Name_matched_author" AS scrubbed_author, 
538
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
539
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
540
   FROM tnrs;
541

    
542

    
543
--
544
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
545
--
546

    
547
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.';
548

    
549

    
550
--
551
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
552
--
553

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

    
604

    
605
--
606
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
607
--
608

    
609
COMMENT ON VIEW taxon_scrub IS '
610
to modify:
611
SELECT "TNRS".taxon_scrub_modify($$
612
 SELECT *, __ AS scrubbed_morphospecies_binomial
613
   FROM "TNRS"."ValidMatchedTaxon"
614
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
615
$$);
616
';
617

    
618

    
619
--
620
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
621
--
622

    
623
ALTER TABLE ONLY batch_download_settings
624
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
625

    
626

    
627
--
628
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
629
--
630

    
631
ALTER TABLE ONLY batch
632
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
633

    
634

    
635
--
636
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
637
--
638

    
639
ALTER TABLE ONLY batch
640
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
641

    
642

    
643
--
644
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
645
--
646

    
647
ALTER TABLE ONLY client_version
648
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
649

    
650

    
651
--
652
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
653
--
654

    
655
ALTER TABLE ONLY tnrs
656
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
657

    
658

    
659
--
660
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
661
--
662

    
663
ALTER TABLE ONLY tnrs
664
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
665

    
666

    
667
--
668
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
669
--
670

    
671
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
672

    
673

    
674
--
675
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
676
--
677

    
678
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
679

    
680

    
681
--
682
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
683
--
684

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

    
687

    
688
--
689
-- Name: tnrs__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
690
--
691

    
692
CREATE TRIGGER tnrs__batch_begin BEFORE INSERT ON tnrs FOR EACH STATEMENT EXECUTE PROCEDURE tnrs__batch_begin();
693

    
694

    
695
--
696
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
697
--
698

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

    
701

    
702
--
703
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
704
--
705

    
706
ALTER TABLE ONLY batch
707
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
708

    
709

    
710
--
711
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
712
--
713

    
714
ALTER TABLE ONLY batch_download_settings
715
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
716

    
717

    
718
--
719
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
720
--
721

    
722
ALTER TABLE ONLY tnrs
723
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
724

    
725

    
726
--
727
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
728
--
729

    
730
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
731
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
732
GRANT ALL ON SCHEMA "TNRS" TO bien;
733
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
734

    
735

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

    
740
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
741
REVOKE ALL ON TABLE tnrs FROM bien;
742
GRANT ALL ON TABLE tnrs TO bien;
743
GRANT SELECT ON TABLE tnrs TO bien_read;
744

    
745

    
746
--
747
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
748
--
749

    
750
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
751
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
752
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
753
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
754

    
755

    
756
--
757
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
758
--
759

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

    
765

    
766
--
767
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
768
--
769

    
770
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
771
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
772
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
773
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
774

    
775

    
776
--
777
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
778
--
779

    
780
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
781
REVOKE ALL ON TABLE taxon_scrub FROM bien;
782
GRANT ALL ON TABLE taxon_scrub TO bien;
783
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
784

    
785

    
786
--
787
-- PostgreSQL database dump complete
788
--
789

    
(8-8/10)