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: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
44
--
45

    
46
CREATE FUNCTION batch__fill() RETURNS trigger
47
    LANGUAGE plpgsql
48
    AS $$
49
BEGIN
50
	new.id_by_time = new.time_submitted;
51
	new.id = COALESCE(new.id, new.id_by_time);
52
	RETURN new;
53
END;
54
$$;
55

    
56

    
57
--
58
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
59
--
60

    
61
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
62
    LANGUAGE sql STABLE STRICT
63
    AS $_$
64
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
65
$_$;
66

    
67

    
68
--
69
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
70
--
71

    
72
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
73
    LANGUAGE sql STABLE STRICT
74
    AS $_$
75
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
76
$_$;
77

    
78

    
79
--
80
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
81
--
82

    
83
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
84
    LANGUAGE sql IMMUTABLE
85
    AS $_$
86
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
87
"taxonomic_status should be accepted instead of synonym when an accepted name is
88
available (this is not always the case when a name is marked as a synonym)" */
89
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
90
$_$;
91

    
92

    
93
--
94
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
95
--
96

    
97
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
98
    LANGUAGE plpgsql
99
    AS $$
100
DECLARE
101
	"Specific_epithet_is_plant" boolean :=
102
		(CASE
103
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
104
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
105
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
106
			THEN true
107
		ELSE NULL -- ambiguous
108
		END);
109
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
110
		-- author disambiguates
111
	family_is_homonym boolean = NOT never_homonym
112
		AND "TNRS".family_is_homonym(new."Family_matched");
113
	genus_is_homonym  boolean = NOT never_homonym
114
		AND "TNRS".genus_is_homonym(new."Genus_matched");
115
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
116
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
117
			new."Name_matched")
118
		, NULLIF(new."Name_matched", 'No suitable matches found.')
119
		, new."Name_matched_author"
120
		), '');
121
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
122
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
123
			new."Accepted_name")
124
		, new."Accepted_name"
125
		, new."Accepted_name_author"
126
		), '');
127
BEGIN
128
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
129
	a name, but the name is not meaningful because it is not unambiguous). */
130
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
131
		AND COALESCE(CASE
132
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
133
			THEN true
134
		ELSE -- consider genus
135
			(CASE
136
			WHEN new."Genus_score" =  1	   -- exact match
137
				THEN
138
				(CASE
139
				WHEN NOT genus_is_homonym THEN true
140
				ELSE "Specific_epithet_is_plant"
141
				END)
142
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
143
				THEN "Specific_epithet_is_plant"
144
			ELSE NULL -- ambiguous
145
			END)
146
		END, false);
147
	new.scrubbed_unique_taxon_name = COALESCE(
148
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
149
	
150
	RETURN new;
151
END;
152
$$;
153

    
154

    
155
--
156
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
157
--
158

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

    
165

    
166
SET default_tablespace = '';
167

    
168
SET default_with_oids = false;
169

    
170
--
171
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
172
--
173

    
174
CREATE TABLE tnrs (
175
    batch text DEFAULT now() NOT NULL,
176
    "Name_number" integer NOT NULL,
177
    "Name_submitted" text NOT NULL,
178
    "Overall_score" double precision,
179
    "Name_matched" text,
180
    "Name_matched_rank" text,
181
    "Name_score" double precision,
182
    "Name_matched_author" text,
183
    "Name_matched_url" text,
184
    "Author_matched" text,
185
    "Author_score" double precision,
186
    "Family_matched" text,
187
    "Family_score" double precision,
188
    "Name_matched_accepted_family" text,
189
    "Genus_matched" text,
190
    "Genus_score" double precision,
191
    "Specific_epithet_matched" text,
192
    "Specific_epithet_score" double precision,
193
    "Infraspecific_rank" text,
194
    "Infraspecific_epithet_matched" text,
195
    "Infraspecific_epithet_score" double precision,
196
    "Infraspecific_rank_2" text,
197
    "Infraspecific_epithet_2_matched" text,
198
    "Infraspecific_epithet_2_score" double precision,
199
    "Annotations" text,
200
    "Unmatched_terms" text,
201
    "Taxonomic_status" text,
202
    "Accepted_name" text,
203
    "Accepted_name_author" text,
204
    "Accepted_name_rank" text,
205
    "Accepted_name_url" text,
206
    "Accepted_name_species" text,
207
    "Accepted_name_family" text,
208
    "Selected" text,
209
    "Source" text,
210
    "Warnings" text,
211
    "Accepted_name_lsid" text,
212
    is_valid_match boolean NOT NULL,
213
    scrubbed_unique_taxon_name text
214
);
215

    
216

    
217
--
218
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
219
--
220

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

    
224

    
225
--
226
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
227
--
228

    
229
CREATE VIEW "MatchedTaxon" AS
230
 SELECT s."*Name_matched.batch", 
231
    s."concatenatedScientificName", 
232
    s."matchedTaxonName", 
233
    s."matchedTaxonRank", 
234
    s."*Name_matched.Name_score", 
235
    s."matchedScientificNameAuthorship", 
236
    s."matchedScientificNameID", 
237
    s."*Name_matched.Author_score", 
238
    s."matchedFamilyConfidence_fraction", 
239
    s."matchedFamily", 
240
    s."matchedGenus", 
241
    s."matchedGenusConfidence_fraction", 
242
    s."matchedSpecificEpithet", 
243
    s."matchedSpeciesConfidence_fraction", 
244
    s."matchedInfraspecificEpithet", 
245
    s."*Name_matched.Infraspecific_epithet_score", 
246
    s."identificationQualifier", 
247
    s."morphospeciesSuffix", 
248
    s."taxonomicStatus", 
249
    s.accepted_taxon_name_no_author, 
250
    s.accepted_author, 
251
    s.accepted_taxon_rank, 
252
    s."acceptedScientificNameID", 
253
    s.accepted_species_binomial, 
254
    s.accepted_family, 
255
    s."*Name_matched.Selected", 
256
    s."*Name_matched.Source", 
257
    s."*Name_matched.Warnings", 
258
    s."*Name_matched.Accepted_name_lsid", 
259
    s.taxon_scrub__is_valid_match, 
260
    s.scrubbed_unique_taxon_name, 
261
        CASE
262
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
263
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
264
            ELSE s.accepted_species_binomial
265
        END AS accepted_morphospecies_binomial
266
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch", 
267
            tnrs."Name_submitted" AS "concatenatedScientificName", 
268
            tnrs."Name_matched" AS "matchedTaxonName", 
269
            tnrs."Name_matched_rank" AS "matchedTaxonRank", 
270
            tnrs."Name_score" AS "*Name_matched.Name_score", 
271
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", 
272
            tnrs."Name_matched_url" AS "matchedScientificNameID", 
273
            tnrs."Author_score" AS "*Name_matched.Author_score", 
274
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction", 
275
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", 
276
            tnrs."Genus_matched" AS "matchedGenus", 
277
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction", 
278
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", 
279
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", 
280
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", 
281
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", 
282
            tnrs."Annotations" AS "identificationQualifier", 
283
            tnrs."Unmatched_terms" AS "morphospeciesSuffix", 
284
            tnrs."Taxonomic_status" AS "taxonomicStatus", 
285
            tnrs."Accepted_name" AS accepted_taxon_name_no_author, 
286
            tnrs."Accepted_name_author" AS accepted_author, 
287
            tnrs."Accepted_name_rank" AS accepted_taxon_rank, 
288
            tnrs."Accepted_name_url" AS "acceptedScientificNameID", 
289
            tnrs."Accepted_name_species" AS accepted_species_binomial, 
290
            tnrs."Accepted_name_family" AS accepted_family, 
291
            tnrs."Selected" AS "*Name_matched.Selected", 
292
            tnrs."Source" AS "*Name_matched.Source", 
293
            tnrs."Warnings" AS "*Name_matched.Warnings", 
294
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", 
295
            tnrs.is_valid_match AS taxon_scrub__is_valid_match, 
296
            tnrs.scrubbed_unique_taxon_name
297
           FROM tnrs) s;
298

    
299

    
300
--
301
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
302
--
303

    
304
COMMENT ON VIEW "MatchedTaxon" IS '
305
to modify:
306
-- use `*, ... AS accepted_morphospecies_binomial` as the column list
307
SELECT util.force_recreate($$
308
-- trigger the dependent_objects_still_exist exception
309
DROP VIEW "TNRS"."MatchedTaxon"; -- *not* CASCADE; it must trigger an exception
310

    
311
CREATE VIEW "TNRS"."MatchedTaxon" AS 
312
SELECT *, ... AS accepted_morphospecies_binomial
313
/*revised def*/
314
;
315
GRANT SELECT ON TABLE "TNRS"."MatchedTaxon" TO bien_read;
316
COMMENT ON VIEW "TNRS"."MatchedTaxon"
317
  IS ''
318
...
319
'';
320

    
321
-- manually restore views that need to be updated for the changes
322
-- **IMPORTANT**: update these as described in the views'' comments
323

    
324
CREATE VIEW "TNRS"."ValidMatchedTaxon" AS 
325
 SELECT *
326
   FROM "TNRS"."MatchedTaxon"
327
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
328
GRANT SELECT ON TABLE "TNRS"."ValidMatchedTaxon" TO bien_read;
329
COMMENT ON VIEW "TNRS"."ValidMatchedTaxon"
330
  IS ''
331
to update, use * as the column list
332
'';
333

    
334
CREATE VIEW "TNRS".taxon_scrub AS 
335
 SELECT *
336
   FROM "TNRS"."ValidMatchedTaxon"
337
   LEFT JOIN "TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name);
338
GRANT SELECT ON TABLE "TNRS".taxon_scrub TO bien_read;
339
COMMENT ON VIEW "TNRS".taxon_scrub
340
  IS ''
341
to update, use * as the column list
342
'';
343
$$);
344
';
345

    
346

    
347
--
348
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
349
--
350

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

    
387

    
388
--
389
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
390
--
391

    
392
COMMENT ON VIEW "ValidMatchedTaxon" IS '
393
to update, use * as the column list
394
';
395

    
396

    
397
--
398
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
399
--
400

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

    
408

    
409
--
410
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
411
--
412

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

    
430

    
431
--
432
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
433
--
434

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

    
437

    
438
--
439
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
440
--
441

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

    
449

    
450
--
451
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
452
--
453

    
454
COMMENT ON TABLE client_version IS 'contains svn revisions';
455

    
456

    
457
--
458
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
459
--
460

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

    
463

    
464
--
465
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
466
--
467

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

    
470

    
471
--
472
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
473
--
474

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

    
477

    
478
--
479
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
480
--
481

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

    
494

    
495
--
496
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
497
--
498

    
499
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.';
500

    
501

    
502
--
503
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
504
--
505

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

    
550

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

    
555
COMMENT ON VIEW taxon_scrub IS '
556
to update, use * as the column list
557
';
558

    
559

    
560
--
561
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
562
--
563

    
564
ALTER TABLE ONLY batch_download_settings
565
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
566

    
567

    
568
--
569
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
570
--
571

    
572
ALTER TABLE ONLY batch
573
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
574

    
575

    
576
--
577
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
578
--
579

    
580
ALTER TABLE ONLY batch
581
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
582

    
583

    
584
--
585
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
586
--
587

    
588
ALTER TABLE ONLY client_version
589
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
590

    
591

    
592
--
593
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
594
--
595

    
596
ALTER TABLE ONLY tnrs
597
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
598

    
599

    
600
--
601
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
602
--
603

    
604
ALTER TABLE ONLY tnrs
605
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
606

    
607

    
608
--
609
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
610
--
611

    
612
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
613

    
614

    
615
--
616
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
617
--
618

    
619
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
620

    
621

    
622
--
623
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
624
--
625

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

    
628

    
629
--
630
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
631
--
632

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

    
635

    
636
--
637
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
638
--
639

    
640
ALTER TABLE ONLY batch
641
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
642

    
643

    
644
--
645
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
646
--
647

    
648
ALTER TABLE ONLY batch_download_settings
649
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
650

    
651

    
652
--
653
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
654
--
655

    
656
ALTER TABLE ONLY tnrs
657
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
658

    
659

    
660
--
661
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
662
--
663

    
664
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
665
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
666
GRANT ALL ON SCHEMA "TNRS" TO bien;
667
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
668

    
669

    
670
--
671
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
672
--
673

    
674
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
675
REVOKE ALL ON TABLE tnrs FROM bien;
676
GRANT ALL ON TABLE tnrs TO bien;
677
GRANT SELECT ON TABLE tnrs TO bien_read;
678

    
679

    
680
--
681
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
682
--
683

    
684
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
685
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
686
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
687
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
688

    
689

    
690
--
691
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
692
--
693

    
694
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
695
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
696
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
697
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
698

    
699

    
700
--
701
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
702
--
703

    
704
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
705
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
706
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
707
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
708

    
709

    
710
--
711
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
712
--
713

    
714
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
715
REVOKE ALL ON TABLE taxon_scrub FROM bien;
716
GRANT ALL ON TABLE taxon_scrub TO bien;
717
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
718

    
719

    
720
--
721
-- PostgreSQL database dump complete
722
--
723

    
(8-8/10)