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

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

    
221

    
222
--
223
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
224
--
225

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

    
232

    
233
SET default_tablespace = '';
234

    
235
SET default_with_oids = false;
236

    
237
--
238
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
239
--
240

    
241
CREATE TABLE tnrs (
242
    batch text DEFAULT now() NOT NULL,
243
    "Name_number" integer NOT NULL,
244
    "Name_submitted" text NOT NULL,
245
    "Overall_score" double precision,
246
    "Name_matched" text,
247
    "Name_matched_rank" text,
248
    "Name_score" double precision,
249
    "Name_matched_author" text,
250
    "Name_matched_url" text,
251
    "Author_matched" text,
252
    "Author_score" double precision,
253
    "Family_matched" text,
254
    "Family_score" double precision,
255
    "Name_matched_accepted_family" text,
256
    "Genus_matched" text,
257
    "Genus_score" double precision,
258
    "Specific_epithet_matched" text,
259
    "Specific_epithet_score" double precision,
260
    "Infraspecific_rank" text,
261
    "Infraspecific_epithet_matched" text,
262
    "Infraspecific_epithet_score" double precision,
263
    "Infraspecific_rank_2" text,
264
    "Infraspecific_epithet_2_matched" text,
265
    "Infraspecific_epithet_2_score" double precision,
266
    "Annotations" text,
267
    "Unmatched_terms" text,
268
    "Taxonomic_status" text,
269
    "Accepted_name" text,
270
    "Accepted_name_author" text,
271
    "Accepted_name_rank" text,
272
    "Accepted_name_url" text,
273
    "Accepted_name_species" text,
274
    "Accepted_name_family" text,
275
    "Selected" text,
276
    "Source" text,
277
    "Warnings" text,
278
    "Accepted_name_lsid" text,
279
    is_valid_match boolean NOT NULL,
280
    scrubbed_unique_taxon_name text
281
);
282

    
283

    
284
--
285
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
286
--
287

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

    
291

    
292
--
293
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
294
--
295

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

    
366

    
367
--
368
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
369
--
370

    
371
COMMENT ON VIEW "MatchedTaxon" IS '
372
to modify:
373
SELECT "TNRS"."MatchedTaxon_modify"($$
374
 SELECT *, __ AS accepted_morphospecies_binomial
375
   FROM __
376
$$);
377
';
378

    
379

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

    
384
CREATE VIEW "ValidMatchedTaxon" AS
385
 SELECT "MatchedTaxon"."*Name_matched.batch", 
386
    "MatchedTaxon"."concatenatedScientificName", 
387
    "MatchedTaxon"."matchedTaxonName", 
388
    "MatchedTaxon"."matchedTaxonRank", 
389
    "MatchedTaxon"."*Name_matched.Name_score", 
390
    "MatchedTaxon"."matchedScientificNameAuthorship", 
391
    "MatchedTaxon"."matchedScientificNameID", 
392
    "MatchedTaxon"."*Name_matched.Author_score", 
393
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
394
    "MatchedTaxon"."matchedFamily", 
395
    "MatchedTaxon"."matchedGenus", 
396
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
397
    "MatchedTaxon"."matchedSpecificEpithet", 
398
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
399
    "MatchedTaxon"."matchedInfraspecificEpithet", 
400
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
401
    "MatchedTaxon"."identificationQualifier", 
402
    "MatchedTaxon"."morphospeciesSuffix", 
403
    "MatchedTaxon"."taxonomicStatus", 
404
    "MatchedTaxon".accepted_taxon_name_no_author, 
405
    "MatchedTaxon".accepted_author, 
406
    "MatchedTaxon".accepted_taxon_rank, 
407
    "MatchedTaxon"."acceptedScientificNameID", 
408
    "MatchedTaxon".accepted_species_binomial, 
409
    "MatchedTaxon".accepted_family, 
410
    "MatchedTaxon"."*Name_matched.Selected", 
411
    "MatchedTaxon"."*Name_matched.Source", 
412
    "MatchedTaxon"."*Name_matched.Warnings", 
413
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
414
    "MatchedTaxon".taxon_scrub__is_valid_match, 
415
    "MatchedTaxon".scrubbed_unique_taxon_name, 
416
    "MatchedTaxon".accepted_morphospecies_binomial
417
   FROM "MatchedTaxon"
418
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
419

    
420

    
421
--
422
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
423
--
424

    
425
COMMENT ON VIEW "ValidMatchedTaxon" IS '
426
to update, use * as the column list
427
';
428

    
429

    
430
--
431
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
432
--
433

    
434
CREATE TABLE batch (
435
    id text NOT NULL,
436
    id_by_time text,
437
    time_submitted timestamp with time zone DEFAULT now(),
438
    client_version text
439
);
440

    
441

    
442
--
443
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
444
--
445

    
446
CREATE TABLE batch_download_settings (
447
    id text NOT NULL,
448
    "E-mail" text,
449
    "Id" text,
450
    "Job type" text,
451
    "Contains Id" boolean,
452
    "Start time" text,
453
    "Finish time" text,
454
    "TNRS version" text,
455
    "Sources selected" text,
456
    "Match threshold" double precision,
457
    "Classification" text,
458
    "Allow partial matches?" boolean,
459
    "Sort by source" boolean,
460
    "Constrain by higher taxonomy" boolean
461
);
462

    
463

    
464
--
465
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
466
--
467

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

    
470

    
471
--
472
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
473
--
474

    
475
CREATE TABLE client_version (
476
    id text NOT NULL,
477
    global_rev integer NOT NULL,
478
    "/lib/tnrs.py rev" integer,
479
    "/bin/tnrs_db rev" integer
480
);
481

    
482

    
483
--
484
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
485
--
486

    
487
COMMENT ON TABLE client_version IS 'contains svn revisions';
488

    
489

    
490
--
491
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
492
--
493

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

    
496

    
497
--
498
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
499
--
500

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

    
503

    
504
--
505
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
506
--
507

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

    
510

    
511
--
512
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
513
--
514

    
515
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
516
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
517
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
518
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
519
    tnrs."Genus_matched" AS scrubbed_genus, 
520
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
521
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
522
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
523
    tnrs."Name_matched_author" AS scrubbed_author, 
524
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author, 
525
    (tnrs."Name_matched" || COALESCE((' '::text || tnrs."Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
526
   FROM tnrs;
527

    
528

    
529
--
530
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
531
--
532

    
533
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.';
534

    
535

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

    
540
CREATE VIEW taxon_scrub AS
541
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
542
    "ValidMatchedTaxon"."*Name_matched.batch", 
543
    "ValidMatchedTaxon"."concatenatedScientificName", 
544
    "ValidMatchedTaxon"."matchedTaxonName", 
545
    "ValidMatchedTaxon"."matchedTaxonRank", 
546
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
547
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
548
    "ValidMatchedTaxon"."matchedScientificNameID", 
549
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
550
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
551
    "ValidMatchedTaxon"."matchedFamily", 
552
    "ValidMatchedTaxon"."matchedGenus", 
553
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
554
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
555
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
556
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
557
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
558
    "ValidMatchedTaxon"."identificationQualifier", 
559
    "ValidMatchedTaxon"."morphospeciesSuffix", 
560
    "ValidMatchedTaxon"."taxonomicStatus", 
561
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
562
    "ValidMatchedTaxon".accepted_author, 
563
    "ValidMatchedTaxon".accepted_taxon_rank, 
564
    "ValidMatchedTaxon"."acceptedScientificNameID", 
565
    "ValidMatchedTaxon".accepted_species_binomial, 
566
    "ValidMatchedTaxon".accepted_family, 
567
    "ValidMatchedTaxon"."*Name_matched.Selected", 
568
    "ValidMatchedTaxon"."*Name_matched.Source", 
569
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
570
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
571
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
572
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
573
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
574
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
575
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
576
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
577
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
578
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
579
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
580
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, 
581
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author, 
582
        CASE
583
            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")
584
            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")
585
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
586
        END AS scrubbed_morphospecies_binomial
587
   FROM ("ValidMatchedTaxon"
588
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
589

    
590

    
591
--
592
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
593
--
594

    
595
COMMENT ON VIEW taxon_scrub IS '
596
to modify:
597
SELECT "TNRS".taxon_scrub_modify($$
598
 SELECT *, __ AS scrubbed_morphospecies_binomial
599
   FROM "TNRS"."ValidMatchedTaxon"
600
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
601
$$);
602
';
603

    
604

    
605
--
606
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
607
--
608

    
609
ALTER TABLE ONLY batch_download_settings
610
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
611

    
612

    
613
--
614
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
615
--
616

    
617
ALTER TABLE ONLY batch
618
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
619

    
620

    
621
--
622
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
623
--
624

    
625
ALTER TABLE ONLY batch
626
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
627

    
628

    
629
--
630
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
631
--
632

    
633
ALTER TABLE ONLY client_version
634
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
635

    
636

    
637
--
638
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
639
--
640

    
641
ALTER TABLE ONLY tnrs
642
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
643

    
644

    
645
--
646
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
647
--
648

    
649
ALTER TABLE ONLY tnrs
650
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
651

    
652

    
653
--
654
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
655
--
656

    
657
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
658

    
659

    
660
--
661
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
662
--
663

    
664
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
665

    
666

    
667
--
668
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
669
--
670

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

    
673

    
674
--
675
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
676
--
677

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

    
680

    
681
--
682
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
683
--
684

    
685
ALTER TABLE ONLY batch
686
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
687

    
688

    
689
--
690
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
691
--
692

    
693
ALTER TABLE ONLY batch_download_settings
694
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
695

    
696

    
697
--
698
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
699
--
700

    
701
ALTER TABLE ONLY tnrs
702
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
703

    
704

    
705
--
706
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
707
--
708

    
709
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
710
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
711
GRANT ALL ON SCHEMA "TNRS" TO bien;
712
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
713

    
714

    
715
--
716
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
717
--
718

    
719
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
720
REVOKE ALL ON TABLE tnrs FROM bien;
721
GRANT ALL ON TABLE tnrs TO bien;
722
GRANT SELECT ON TABLE tnrs TO bien_read;
723

    
724

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

    
729
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
730
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
731
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
732
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
733

    
734

    
735
--
736
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
737
--
738

    
739
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
740
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
741
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
742
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
743

    
744

    
745
--
746
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
747
--
748

    
749
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
750
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
751
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
752
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
753

    
754

    
755
--
756
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
757
--
758

    
759
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
760
REVOKE ALL ON TABLE taxon_scrub FROM bien;
761
GRANT ALL ON TABLE taxon_scrub TO bien;
762
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
763

    
764

    
765
--
766
-- PostgreSQL database dump complete
767
--
768

    
(8-8/10)