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: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
135
--
136

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

    
194

    
195
--
196
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
197
--
198

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

    
205

    
206
SET default_tablespace = '';
207

    
208
SET default_with_oids = false;
209

    
210
--
211
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
212
--
213

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

    
256

    
257
--
258
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
259
--
260

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

    
264

    
265
--
266
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
267
--
268

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

    
339

    
340
--
341
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
342
--
343

    
344
COMMENT ON VIEW "MatchedTaxon" IS '
345
to modify:
346
SELECT "TNRS"."MatchedTaxon_modify"($$
347
 SELECT *, __ AS accepted_morphospecies_binomial
348
   FROM __
349
$$);
350
';
351

    
352

    
353
--
354
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
355
--
356

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

    
393

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

    
398
COMMENT ON VIEW "ValidMatchedTaxon" IS '
399
to update, use * as the column list
400
';
401

    
402

    
403
--
404
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
405
--
406

    
407
CREATE TABLE batch (
408
    id text NOT NULL,
409
    id_by_time text,
410
    time_submitted timestamp with time zone DEFAULT now(),
411
    client_version text
412
);
413

    
414

    
415
--
416
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
417
--
418

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

    
436

    
437
--
438
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
439
--
440

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

    
443

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

    
448
CREATE TABLE client_version (
449
    id text NOT NULL,
450
    global_rev integer NOT NULL,
451
    "/lib/tnrs.py rev" integer,
452
    "/bin/tnrs_db rev" integer
453
);
454

    
455

    
456
--
457
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
458
--
459

    
460
COMMENT ON TABLE client_version IS 'contains svn revisions';
461

    
462

    
463
--
464
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
465
--
466

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

    
469

    
470
--
471
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
472
--
473

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

    
476

    
477
--
478
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
479
--
480

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

    
483

    
484
--
485
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
486
--
487

    
488
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
489
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, 
490
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank, 
491
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family, 
492
    tnrs."Genus_matched" AS scrubbed_genus, 
493
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, 
494
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, 
495
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, 
496
    tnrs."Name_matched_author" AS scrubbed_author, 
497
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
498
   FROM tnrs;
499

    
500

    
501
--
502
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
503
--
504

    
505
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.';
506

    
507

    
508
--
509
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
510
--
511

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

    
556

    
557
--
558
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
559
--
560

    
561
COMMENT ON VIEW taxon_scrub IS '
562
to update, use * as the column list
563
';
564

    
565

    
566
--
567
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
568
--
569

    
570
ALTER TABLE ONLY batch_download_settings
571
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
572

    
573

    
574
--
575
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
576
--
577

    
578
ALTER TABLE ONLY batch
579
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
580

    
581

    
582
--
583
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
584
--
585

    
586
ALTER TABLE ONLY batch
587
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
588

    
589

    
590
--
591
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
592
--
593

    
594
ALTER TABLE ONLY client_version
595
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
596

    
597

    
598
--
599
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
600
--
601

    
602
ALTER TABLE ONLY tnrs
603
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
604

    
605

    
606
--
607
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
608
--
609

    
610
ALTER TABLE ONLY tnrs
611
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
612

    
613

    
614
--
615
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
616
--
617

    
618
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
619

    
620

    
621
--
622
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
623
--
624

    
625
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
626

    
627

    
628
--
629
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
630
--
631

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

    
634

    
635
--
636
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
637
--
638

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

    
641

    
642
--
643
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
644
--
645

    
646
ALTER TABLE ONLY batch
647
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
648

    
649

    
650
--
651
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
652
--
653

    
654
ALTER TABLE ONLY batch_download_settings
655
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
656

    
657

    
658
--
659
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
660
--
661

    
662
ALTER TABLE ONLY tnrs
663
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
664

    
665

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

    
670
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
671
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
672
GRANT ALL ON SCHEMA "TNRS" TO bien;
673
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
674

    
675

    
676
--
677
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
678
--
679

    
680
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
681
REVOKE ALL ON TABLE tnrs FROM bien;
682
GRANT ALL ON TABLE tnrs TO bien;
683
GRANT SELECT ON TABLE tnrs TO bien_read;
684

    
685

    
686
--
687
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
688
--
689

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

    
695

    
696
--
697
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
698
--
699

    
700
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
701
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
702
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
703
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
704

    
705

    
706
--
707
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
708
--
709

    
710
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
711
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
712
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
713
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
714

    
715

    
716
--
717
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
718
--
719

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

    
725

    
726
--
727
-- PostgreSQL database dump complete
728
--
729

    
(8-8/10)