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($$
50
CREATE VIEW "TNRS"."MatchedTaxon" AS 
51
$$||$1||$$
52
;
53
$$||util.mk_set_relation_metadata('"TNRS"."MatchedTaxon"')||$$
54

    
55
-- manually restore views that need to be updated for the changes
56
-- **IMPORTANT**: keep these updated as described in the views' comments
57

    
58
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
59
 SELECT *
60
   FROM "TNRS"."MatchedTaxon"
61
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
62
$$||util.mk_set_relation_metadata('"TNRS"."ValidMatchedTaxon"')||$$
63

    
64
CREATE VIEW "TNRS".taxon_scrub AS 
65
 SELECT *
66
   FROM "TNRS"."ValidMatchedTaxon"
67
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
68
$$||util.mk_set_relation_metadata('"TNRS".taxon_scrub')||$$
69
$$);
70
$_$;
71

    
72

    
73
--
74
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
75
--
76

    
77
CREATE FUNCTION batch__fill() RETURNS trigger
78
    LANGUAGE plpgsql
79
    AS $$
80
BEGIN
81
	new.id_by_time = new.time_submitted;
82
	new.id = COALESCE(new.id, new.id_by_time);
83
	RETURN new;
84
END;
85
$$;
86

    
87

    
88
--
89
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
90
--
91

    
92
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
93
    LANGUAGE sql STABLE STRICT
94
    AS $_$
95
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
96
$_$;
97

    
98

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

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

    
109

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

    
114
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
115
    LANGUAGE sql IMMUTABLE
116
    AS $_$
117
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
118
"taxonomic_status should be accepted instead of synonym when an accepted name is
119
available (this is not always the case when a name is marked as a synonym)" */
120
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
121
$_$;
122

    
123

    
124
--
125
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
126
--
127

    
128
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
129
    LANGUAGE plpgsql
130
    AS $$
131
DECLARE
132
	"Specific_epithet_is_plant" boolean :=
133
		(CASE
134
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
135
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
136
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
137
			THEN true
138
		ELSE NULL -- ambiguous
139
		END);
140
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
141
		-- author disambiguates
142
	family_is_homonym boolean = NOT never_homonym
143
		AND "TNRS".family_is_homonym(new."Family_matched");
144
	genus_is_homonym  boolean = NOT never_homonym
145
		AND "TNRS".genus_is_homonym(new."Genus_matched");
146
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
147
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
148
			new."Name_matched")
149
		, NULLIF(new."Name_matched", 'No suitable matches found.')
150
		, new."Name_matched_author"
151
		), '');
152
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
153
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
154
			new."Accepted_name")
155
		, new."Accepted_name"
156
		, new."Accepted_name_author"
157
		), '');
158
BEGIN
159
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
160
	a name, but the name is not meaningful because it is not unambiguous). */
161
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
162
		AND COALESCE(CASE
163
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
164
			THEN true
165
		ELSE -- consider genus
166
			(CASE
167
			WHEN new."Genus_score" =  1	   -- exact match
168
				THEN
169
				(CASE
170
				WHEN NOT genus_is_homonym THEN true
171
				ELSE "Specific_epithet_is_plant"
172
				END)
173
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
174
				THEN "Specific_epithet_is_plant"
175
			ELSE NULL -- ambiguous
176
			END)
177
		END, false);
178
	new.scrubbed_unique_taxon_name = COALESCE(
179
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
180
	
181
	RETURN new;
182
END;
183
$$;
184

    
185

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

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

    
196

    
197
SET default_tablespace = '';
198

    
199
SET default_with_oids = false;
200

    
201
--
202
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
203
--
204

    
205
CREATE TABLE tnrs (
206
    batch text DEFAULT now() NOT NULL,
207
    "Name_number" integer NOT NULL,
208
    "Name_submitted" text NOT NULL,
209
    "Overall_score" double precision,
210
    "Name_matched" text,
211
    "Name_matched_rank" text,
212
    "Name_score" double precision,
213
    "Name_matched_author" text,
214
    "Name_matched_url" text,
215
    "Author_matched" text,
216
    "Author_score" double precision,
217
    "Family_matched" text,
218
    "Family_score" double precision,
219
    "Name_matched_accepted_family" text,
220
    "Genus_matched" text,
221
    "Genus_score" double precision,
222
    "Specific_epithet_matched" text,
223
    "Specific_epithet_score" double precision,
224
    "Infraspecific_rank" text,
225
    "Infraspecific_epithet_matched" text,
226
    "Infraspecific_epithet_score" double precision,
227
    "Infraspecific_rank_2" text,
228
    "Infraspecific_epithet_2_matched" text,
229
    "Infraspecific_epithet_2_score" double precision,
230
    "Annotations" text,
231
    "Unmatched_terms" text,
232
    "Taxonomic_status" text,
233
    "Accepted_name" text,
234
    "Accepted_name_author" text,
235
    "Accepted_name_rank" text,
236
    "Accepted_name_url" text,
237
    "Accepted_name_species" text,
238
    "Accepted_name_family" text,
239
    "Selected" text,
240
    "Source" text,
241
    "Warnings" text,
242
    "Accepted_name_lsid" text,
243
    is_valid_match boolean NOT NULL,
244
    scrubbed_unique_taxon_name text
245
);
246

    
247

    
248
--
249
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
250
--
251

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

    
255

    
256
--
257
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
258
--
259

    
260
CREATE VIEW "MatchedTaxon" AS
261
 SELECT s."*Name_matched.batch", 
262
    s."concatenatedScientificName", 
263
    s."matchedTaxonName", 
264
    s."matchedTaxonRank", 
265
    s."*Name_matched.Name_score", 
266
    s."matchedScientificNameAuthorship", 
267
    s."matchedScientificNameID", 
268
    s."*Name_matched.Author_score", 
269
    s."matchedFamilyConfidence_fraction", 
270
    s."matchedFamily", 
271
    s."matchedGenus", 
272
    s."matchedGenusConfidence_fraction", 
273
    s."matchedSpecificEpithet", 
274
    s."matchedSpeciesConfidence_fraction", 
275
    s."matchedInfraspecificEpithet", 
276
    s."*Name_matched.Infraspecific_epithet_score", 
277
    s."identificationQualifier", 
278
    s."morphospeciesSuffix", 
279
    s."taxonomicStatus", 
280
    s.accepted_taxon_name_no_author, 
281
    s.accepted_author, 
282
    s.accepted_taxon_rank, 
283
    s."acceptedScientificNameID", 
284
    s.accepted_species_binomial, 
285
    s.accepted_family, 
286
    s."*Name_matched.Selected", 
287
    s."*Name_matched.Source", 
288
    s."*Name_matched.Warnings", 
289
    s."*Name_matched.Accepted_name_lsid", 
290
    s.taxon_scrub__is_valid_match, 
291
    s.scrubbed_unique_taxon_name, 
292
        CASE
293
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
294
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
295
            ELSE s.accepted_species_binomial
296
        END AS accepted_morphospecies_binomial
297
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
298
            tnrs."Name_submitted" AS "concatenatedScientificName", 
299
            tnrs."Name_matched" AS "matchedTaxonName", 
300
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
301
            tnrs."Name_score" AS "*Name_matched.Name_score", 
302
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
303
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
304
            tnrs."Author_score" AS "*Name_matched.Author_score", 
305
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
306
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
307
            tnrs."Genus_matched" AS "matchedGenus", 
308
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
309
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
310
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
311
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
312
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
313
            tnrs."Annotations" AS "identificationQualifier", 
314
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
315
            map_taxonomic_status(tnrs."Taxonomic_status", tnrs."Accepted_name") AS "taxonomicStatus", 
316
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
317
            tnrs."Accepted_name_author" AS accepted_author, 
318
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
319
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
320
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
321
            tnrs."Accepted_name_family" AS accepted_family, 
322
            tnrs."Selected" AS "*Name_matched.Selected", 
323
            tnrs."Source" AS "*Name_matched.Source", 
324
            tnrs."Warnings" AS "*Name_matched.Warnings", 
325
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
326
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
327
            tnrs.scrubbed_unique_taxon_name
328
           FROM tnrs) s;
329

    
330

    
331
--
332
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
333
--
334

    
335
COMMENT ON VIEW "MatchedTaxon" IS '
336
to modify:
337
SELECT "TNRS"."MatchedTaxon_modify"($$
338
 SELECT *, __ AS accepted_morphospecies_binomial
339
   FROM __
340
$$);
341
';
342

    
343

    
344
--
345
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
346
--
347

    
348
CREATE VIEW "ValidMatchedTaxon" AS
349
 SELECT "MatchedTaxon"."*Name_matched.batch", 
350
    "MatchedTaxon"."concatenatedScientificName", 
351
    "MatchedTaxon"."matchedTaxonName", 
352
    "MatchedTaxon"."matchedTaxonRank", 
353
    "MatchedTaxon"."*Name_matched.Name_score", 
354
    "MatchedTaxon"."matchedScientificNameAuthorship", 
355
    "MatchedTaxon"."matchedScientificNameID", 
356
    "MatchedTaxon"."*Name_matched.Author_score", 
357
    "MatchedTaxon"."matchedFamilyConfidence_fraction", 
358
    "MatchedTaxon"."matchedFamily", 
359
    "MatchedTaxon"."matchedGenus", 
360
    "MatchedTaxon"."matchedGenusConfidence_fraction", 
361
    "MatchedTaxon"."matchedSpecificEpithet", 
362
    "MatchedTaxon"."matchedSpeciesConfidence_fraction", 
363
    "MatchedTaxon"."matchedInfraspecificEpithet", 
364
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
365
    "MatchedTaxon"."identificationQualifier", 
366
    "MatchedTaxon"."morphospeciesSuffix", 
367
    "MatchedTaxon"."taxonomicStatus", 
368
    "MatchedTaxon".accepted_taxon_name_no_author, 
369
    "MatchedTaxon".accepted_author, 
370
    "MatchedTaxon".accepted_taxon_rank, 
371
    "MatchedTaxon"."acceptedScientificNameID", 
372
    "MatchedTaxon".accepted_species_binomial, 
373
    "MatchedTaxon".accepted_family, 
374
    "MatchedTaxon"."*Name_matched.Selected", 
375
    "MatchedTaxon"."*Name_matched.Source", 
376
    "MatchedTaxon"."*Name_matched.Warnings", 
377
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid", 
378
    "MatchedTaxon".taxon_scrub__is_valid_match, 
379
    "MatchedTaxon".scrubbed_unique_taxon_name, 
380
    "MatchedTaxon".accepted_morphospecies_binomial
381
   FROM "MatchedTaxon"
382
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
383

    
384

    
385
--
386
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
387
--
388

    
389
COMMENT ON VIEW "ValidMatchedTaxon" IS '
390
to update, use * as the column list
391
';
392

    
393

    
394
--
395
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
396
--
397

    
398
CREATE TABLE batch (
399
    id text NOT NULL,
400
    id_by_time text,
401
    time_submitted timestamp with time zone DEFAULT now(),
402
    client_version text
403
);
404

    
405

    
406
--
407
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
408
--
409

    
410
CREATE TABLE batch_download_settings (
411
    id text NOT NULL,
412
    "E-mail" text,
413
    "Id" text,
414
    "Job type" text,
415
    "Contains Id" boolean,
416
    "Start time" text,
417
    "Finish time" text,
418
    "TNRS version" text,
419
    "Sources selected" text,
420
    "Match threshold" double precision,
421
    "Classification" text,
422
    "Allow partial matches?" boolean,
423
    "Sort by source" boolean,
424
    "Constrain by higher taxonomy" boolean
425
);
426

    
427

    
428
--
429
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
430
--
431

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

    
434

    
435
--
436
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
437
--
438

    
439
CREATE TABLE client_version (
440
    id text NOT NULL,
441
    global_rev integer NOT NULL,
442
    "/lib/tnrs.py rev" integer,
443
    "/bin/tnrs_db rev" integer
444
);
445

    
446

    
447
--
448
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
449
--
450

    
451
COMMENT ON TABLE client_version IS 'contains svn revisions';
452

    
453

    
454
--
455
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
456
--
457

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

    
460

    
461
--
462
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
463
--
464

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

    
467

    
468
--
469
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
470
--
471

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

    
474

    
475
--
476
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
477
--
478

    
479
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
480
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
481
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
482
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
483
    tnrs."Genus_matched" AS scrubbed_genus, 
484
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
485
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
486
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
487
    tnrs."Name_matched_author" AS scrubbed_author, 
488
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
489
   FROM tnrs;
490

    
491

    
492
--
493
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
494
--
495

    
496
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.';
497

    
498

    
499
--
500
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
501
--
502

    
503
CREATE VIEW taxon_scrub AS
504
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, 
505
    "ValidMatchedTaxon"."*Name_matched.batch", 
506
    "ValidMatchedTaxon"."concatenatedScientificName", 
507
    "ValidMatchedTaxon"."matchedTaxonName", 
508
    "ValidMatchedTaxon"."matchedTaxonRank", 
509
    "ValidMatchedTaxon"."*Name_matched.Name_score", 
510
    "ValidMatchedTaxon"."matchedScientificNameAuthorship", 
511
    "ValidMatchedTaxon"."matchedScientificNameID", 
512
    "ValidMatchedTaxon"."*Name_matched.Author_score", 
513
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", 
514
    "ValidMatchedTaxon"."matchedFamily", 
515
    "ValidMatchedTaxon"."matchedGenus", 
516
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction", 
517
    "ValidMatchedTaxon"."matchedSpecificEpithet", 
518
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", 
519
    "ValidMatchedTaxon"."matchedInfraspecificEpithet", 
520
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", 
521
    "ValidMatchedTaxon"."identificationQualifier", 
522
    "ValidMatchedTaxon"."morphospeciesSuffix", 
523
    "ValidMatchedTaxon"."taxonomicStatus", 
524
    "ValidMatchedTaxon".accepted_taxon_name_no_author, 
525
    "ValidMatchedTaxon".accepted_author, 
526
    "ValidMatchedTaxon".accepted_taxon_rank, 
527
    "ValidMatchedTaxon"."acceptedScientificNameID", 
528
    "ValidMatchedTaxon".accepted_species_binomial, 
529
    "ValidMatchedTaxon".accepted_family, 
530
    "ValidMatchedTaxon"."*Name_matched.Selected", 
531
    "ValidMatchedTaxon"."*Name_matched.Source", 
532
    "ValidMatchedTaxon"."*Name_matched.Warnings", 
533
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", 
534
    "ValidMatchedTaxon".taxon_scrub__is_valid_match, 
535
    "ValidMatchedTaxon".accepted_morphospecies_binomial, 
536
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, 
537
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, 
538
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, 
539
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, 
540
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, 
541
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, 
542
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, 
543
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author
544
   FROM ("ValidMatchedTaxon"
545
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
546

    
547

    
548
--
549
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
550
--
551

    
552
COMMENT ON VIEW taxon_scrub IS '
553
to update, use * as the column list
554
';
555

    
556

    
557
--
558
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
559
--
560

    
561
ALTER TABLE ONLY batch_download_settings
562
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
563

    
564

    
565
--
566
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
567
--
568

    
569
ALTER TABLE ONLY batch
570
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
571

    
572

    
573
--
574
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
575
--
576

    
577
ALTER TABLE ONLY batch
578
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
579

    
580

    
581
--
582
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
583
--
584

    
585
ALTER TABLE ONLY client_version
586
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
587

    
588

    
589
--
590
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
591
--
592

    
593
ALTER TABLE ONLY tnrs
594
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
595

    
596

    
597
--
598
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
599
--
600

    
601
ALTER TABLE ONLY tnrs
602
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
603

    
604

    
605
--
606
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
607
--
608

    
609
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
610

    
611

    
612
--
613
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
614
--
615

    
616
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
617

    
618

    
619
--
620
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
621
--
622

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

    
625

    
626
--
627
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
628
--
629

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

    
632

    
633
--
634
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
635
--
636

    
637
ALTER TABLE ONLY batch
638
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
639

    
640

    
641
--
642
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
643
--
644

    
645
ALTER TABLE ONLY batch_download_settings
646
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
647

    
648

    
649
--
650
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
651
--
652

    
653
ALTER TABLE ONLY tnrs
654
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
655

    
656

    
657
--
658
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
659
--
660

    
661
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
662
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
663
GRANT ALL ON SCHEMA "TNRS" TO bien;
664
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
665

    
666

    
667
--
668
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
669
--
670

    
671
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
672
REVOKE ALL ON TABLE tnrs FROM bien;
673
GRANT ALL ON TABLE tnrs TO bien;
674
GRANT SELECT ON TABLE tnrs TO bien_read;
675

    
676

    
677
--
678
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
679
--
680

    
681
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
682
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
683
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
684
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
685

    
686

    
687
--
688
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
689
--
690

    
691
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
692
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
693
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
694
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
695

    
696

    
697
--
698
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
699
--
700

    
701
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
702
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
703
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
704
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
705

    
706

    
707
--
708
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
709
--
710

    
711
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
712
REVOKE ALL ON TABLE taxon_scrub FROM bien;
713
GRANT ALL ON TABLE taxon_scrub TO bien;
714
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
715

    
716

    
717
--
718
-- PostgreSQL database dump complete
719
--
720

    
(8-8/10)