Project

General

Profile

1 10778 aaronmk
--
2
-- PostgreSQL database dump
3
--
4 10737 aaronmk
5 10778 aaronmk
SET statement_timeout = 0;
6 11708 aaronmk
SET lock_timeout = 0;
7 10778 aaronmk
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11
12 10737 aaronmk
--
13 10778 aaronmk
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
14
--
15 10737 aaronmk
16 10778 aaronmk
--CREATE SCHEMA "TNRS";
17 10725 aaronmk
18
19 11614 aaronmk
--
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 11617 aaronmk
on vegbiendev:
25
# back up existing TNRS schema (in case of an accidental incorrect change):
26 11614 aaronmk
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
27 11616 aaronmk
$ svn up
28
$ svn di
29
# make the changes shown in the diff
30
## to change column types:
31 11614 aaronmk
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
32
  (''col'', ''new_type'')
33 11616 aaronmk
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
34 11617 aaronmk
$ 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 11614 aaronmk
39
40 10778 aaronmk
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 10728 aaronmk
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 10778 aaronmk
$$;
55 10728 aaronmk
56
57
--
58 10778 aaronmk
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
59
--
60 10728 aaronmk
61 10778 aaronmk
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 10736 aaronmk
67 10778 aaronmk
68 10736 aaronmk
--
69 10778 aaronmk
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
70
--
71 10736 aaronmk
72 10778 aaronmk
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 7844 aaronmk
78 9985 aaronmk
79 10778 aaronmk
--
80 11709 aaronmk
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
81
--
82
83
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, scrubbed_unique_taxon_name text) RETURNS text
84
    LANGUAGE sql IMMUTABLE
85
    AS $_$
86
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
87
$_$;
88
89
90
--
91 10778 aaronmk
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
92
--
93
94
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
95
    LANGUAGE plpgsql
96
    AS $$
97 9763 aaronmk
DECLARE
98 11628 aaronmk
	"Specific_epithet_is_plant" boolean :=
99
		(CASE
100
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
101
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
102
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
103
			THEN true
104
		ELSE NULL -- ambiguous
105
		END);
106
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
107
		-- author disambiguates
108
	family_is_homonym boolean = NOT never_homonym
109
		AND "TNRS".family_is_homonym(new."Family_matched");
110
	genus_is_homonym  boolean = NOT never_homonym
111
		AND "TNRS".genus_is_homonym(new."Genus_matched");
112
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
113
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
114
			new."Name_matched")
115
		, NULLIF(new."Name_matched", 'No suitable matches found.')
116
		, new."Name_matched_author"
117
		), '');
118 11643 aaronmk
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
119 11628 aaronmk
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
120
			new."Accepted_name")
121
		, new."Accepted_name"
122
		, new."Accepted_name_author"
123
		), '');
124 11643 aaronmk
BEGIN
125 11629 aaronmk
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
126
	a name, but the name is not meaningful because it is not unambiguous). */
127 11711 aaronmk
	new.is_valid_match = new."Taxonomic_status" != 'Invalid'
128
		AND COALESCE(CASE
129 11628 aaronmk
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
130
			THEN true
131
		ELSE -- consider genus
132
			(CASE
133
			WHEN new."Genus_score" =  1	   -- exact match
134
				THEN
135
				(CASE
136
				WHEN NOT genus_is_homonym THEN true
137
				ELSE "Specific_epithet_is_plant"
138
				END)
139
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
140
				THEN "Specific_epithet_is_plant"
141
			ELSE NULL -- ambiguous
142
			END)
143 11629 aaronmk
		END, false);
144 11632 aaronmk
	new.scrubbed_unique_taxon_name = COALESCE(
145 11643 aaronmk
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
146 11628 aaronmk
147
	RETURN new;
148 7134 aaronmk
END;
149 10778 aaronmk
$$;
150
151
152
--
153
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
154
--
155
156 10754 aaronmk
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
157
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
158 11715 aaronmk
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
159 10754 aaronmk
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
160 11615 aaronmk
runtime: 1.5 min ("92633 ms")';
161 7134 aaronmk
162 7251 aaronmk
163 10778 aaronmk
SET default_tablespace = '';
164
165
SET default_with_oids = false;
166
167 10728 aaronmk
--
168 10778 aaronmk
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
169
--
170 7251 aaronmk
171 10778 aaronmk
CREATE TABLE tnrs (
172
    batch text DEFAULT now() NOT NULL,
173
    "Name_number" integer NOT NULL,
174
    "Name_submitted" text NOT NULL,
175
    "Overall_score" double precision,
176
    "Name_matched" text,
177
    "Name_matched_rank" text,
178
    "Name_score" double precision,
179
    "Name_matched_author" text,
180
    "Name_matched_url" text,
181
    "Author_matched" text,
182
    "Author_score" double precision,
183
    "Family_matched" text,
184
    "Family_score" double precision,
185
    "Name_matched_accepted_family" text,
186
    "Genus_matched" text,
187
    "Genus_score" double precision,
188
    "Specific_epithet_matched" text,
189
    "Specific_epithet_score" double precision,
190
    "Infraspecific_rank" text,
191
    "Infraspecific_epithet_matched" text,
192
    "Infraspecific_epithet_score" double precision,
193
    "Infraspecific_rank_2" text,
194
    "Infraspecific_epithet_2_matched" text,
195
    "Infraspecific_epithet_2_score" double precision,
196
    "Annotations" text,
197
    "Unmatched_terms" text,
198
    "Taxonomic_status" text,
199
    "Accepted_name" text,
200
    "Accepted_name_author" text,
201
    "Accepted_name_rank" text,
202
    "Accepted_name_url" text,
203
    "Accepted_name_species" text,
204
    "Accepted_name_family" text,
205
    "Selected" text,
206
    "Source" text,
207
    "Warnings" text,
208
    "Accepted_name_lsid" text,
209 11628 aaronmk
    is_valid_match boolean NOT NULL,
210 11632 aaronmk
    scrubbed_unique_taxon_name text
211 10778 aaronmk
);
212 7823 aaronmk
213 9759 aaronmk
214 10778 aaronmk
--
215
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
216
--
217 7823 aaronmk
218 10787 aaronmk
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
219 11614 aaronmk
$ inputs/.TNRS/data.sql.run refresh';
220 10778 aaronmk
221
222
--
223
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
224
--
225
226
CREATE VIEW "MatchedTaxon" AS
227 13498 aaronmk
 SELECT s."*Name_matched.batch",
228
    s."concatenatedScientificName",
229
    s."matchedTaxonName",
230
    s."matchedTaxonRank",
231
    s."*Name_matched.Name_score",
232
    s."matchedScientificNameAuthorship",
233
    s."matchedScientificNameID",
234
    s."*Name_matched.Author_score",
235
    s."matchedFamilyConfidence_fraction",
236
    s."matchedFamily",
237
    s."matchedGenus",
238
    s."matchedGenusConfidence_fraction",
239
    s."matchedSpecificEpithet",
240
    s."matchedSpeciesConfidence_fraction",
241
    s."matchedInfraspecificEpithet",
242
    s."*Name_matched.Infraspecific_epithet_score",
243
    s."identificationQualifier",
244
    s."morphospeciesSuffix",
245
    s."taxonomicStatus",
246
    s.accepted_taxon_name_no_author,
247
    s.accepted_author,
248
    s.accepted_taxon_rank,
249
    s."acceptedScientificNameID",
250
    s.accepted_species_binomial,
251
    s.accepted_family,
252
    s."*Name_matched.Selected",
253
    s."*Name_matched.Source",
254
    s."*Name_matched.Warnings",
255
    s."*Name_matched.Accepted_name_lsid",
256
    s.taxon_scrub__is_valid_match,
257
    s.scrubbed_unique_taxon_name,
258
        CASE
259
            WHEN (s.accepted_taxon_rank = 'family'::text) THEN concat_ws(' '::text, s.accepted_family, s."morphospeciesSuffix")
260
            WHEN (s.accepted_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, s.accepted_taxon_name_no_author, s."morphospeciesSuffix")
261
            ELSE s.accepted_species_binomial
262
        END AS accepted_morphospecies_binomial
263
   FROM ( SELECT tnrs.batch AS "*Name_matched.batch",
264
            tnrs."Name_submitted" AS "concatenatedScientificName",
265
            tnrs."Name_matched" AS "matchedTaxonName",
266
            tnrs."Name_matched_rank" AS "matchedTaxonRank",
267
            tnrs."Name_score" AS "*Name_matched.Name_score",
268
            tnrs."Name_matched_author" AS "matchedScientificNameAuthorship",
269
            tnrs."Name_matched_url" AS "matchedScientificNameID",
270
            tnrs."Author_score" AS "*Name_matched.Author_score",
271
            tnrs."Family_score" AS "matchedFamilyConfidence_fraction",
272
            COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily",
273
            tnrs."Genus_matched" AS "matchedGenus",
274
            tnrs."Genus_score" AS "matchedGenusConfidence_fraction",
275
            tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet",
276
            tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction",
277
            tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet",
278
            tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score",
279
            tnrs."Annotations" AS "identificationQualifier",
280
            tnrs."Unmatched_terms" AS "morphospeciesSuffix",
281
            tnrs."Taxonomic_status" AS "taxonomicStatus",
282
            tnrs."Accepted_name" AS accepted_taxon_name_no_author,
283
            tnrs."Accepted_name_author" AS accepted_author,
284
            tnrs."Accepted_name_rank" AS accepted_taxon_rank,
285
            tnrs."Accepted_name_url" AS "acceptedScientificNameID",
286
            tnrs."Accepted_name_species" AS accepted_species_binomial,
287
            tnrs."Accepted_name_family" AS accepted_family,
288
            tnrs."Selected" AS "*Name_matched.Selected",
289
            tnrs."Source" AS "*Name_matched.Source",
290
            tnrs."Warnings" AS "*Name_matched.Warnings",
291
            tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid",
292
            tnrs.is_valid_match AS taxon_scrub__is_valid_match,
293
            tnrs.scrubbed_unique_taxon_name
294
           FROM tnrs) s;
295 10778 aaronmk
296
297
--
298 13498 aaronmk
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
299
--
300
301
COMMENT ON VIEW "MatchedTaxon" IS '
302
to update, use `*, ... AS accepted_morphospecies_binomial` as the column list
303
';
304
305
306
--
307 10778 aaronmk
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
308
--
309
310
CREATE VIEW "ValidMatchedTaxon" AS
311 11708 aaronmk
 SELECT "MatchedTaxon"."*Name_matched.batch",
312
    "MatchedTaxon"."concatenatedScientificName",
313
    "MatchedTaxon"."matchedTaxonName",
314
    "MatchedTaxon"."matchedTaxonRank",
315
    "MatchedTaxon"."*Name_matched.Name_score",
316
    "MatchedTaxon"."matchedScientificNameAuthorship",
317
    "MatchedTaxon"."matchedScientificNameID",
318
    "MatchedTaxon"."*Name_matched.Author_score",
319
    "MatchedTaxon"."matchedFamilyConfidence_fraction",
320
    "MatchedTaxon"."matchedFamily",
321
    "MatchedTaxon"."matchedGenus",
322
    "MatchedTaxon"."matchedGenusConfidence_fraction",
323
    "MatchedTaxon"."matchedSpecificEpithet",
324
    "MatchedTaxon"."matchedSpeciesConfidence_fraction",
325
    "MatchedTaxon"."matchedInfraspecificEpithet",
326
    "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
327
    "MatchedTaxon"."identificationQualifier",
328
    "MatchedTaxon"."morphospeciesSuffix",
329
    "MatchedTaxon"."taxonomicStatus",
330 13441 aaronmk
    "MatchedTaxon".accepted_taxon_name_no_author,
331
    "MatchedTaxon".accepted_author,
332
    "MatchedTaxon".accepted_taxon_rank,
333 11708 aaronmk
    "MatchedTaxon"."acceptedScientificNameID",
334 13444 aaronmk
    "MatchedTaxon".accepted_species_binomial,
335 13441 aaronmk
    "MatchedTaxon".accepted_family,
336 11708 aaronmk
    "MatchedTaxon"."*Name_matched.Selected",
337
    "MatchedTaxon"."*Name_matched.Source",
338
    "MatchedTaxon"."*Name_matched.Warnings",
339
    "MatchedTaxon"."*Name_matched.Accepted_name_lsid",
340
    "MatchedTaxon".taxon_scrub__is_valid_match,
341 13498 aaronmk
    "MatchedTaxon".scrubbed_unique_taxon_name,
342
    "MatchedTaxon".accepted_morphospecies_binomial
343 11708 aaronmk
   FROM "MatchedTaxon"
344
  WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
345 10778 aaronmk
346
347
--
348
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
349
--
350
351 13443 aaronmk
COMMENT ON VIEW "ValidMatchedTaxon" IS '
352
to update, use * as the column list
353
';
354 10778 aaronmk
355
356
--
357
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
358
--
359
360
CREATE TABLE batch (
361
    id text NOT NULL,
362
    id_by_time text,
363
    time_submitted timestamp with time zone DEFAULT now(),
364
    client_version text
365
);
366
367
368
--
369
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
370
--
371
372
CREATE TABLE batch_download_settings (
373
    id text NOT NULL,
374
    "E-mail" text,
375
    "Id" text,
376
    "Job type" text,
377
    "Contains Id" boolean,
378
    "Start time" text,
379
    "Finish time" text,
380
    "TNRS version" text,
381
    "Sources selected" text,
382
    "Match threshold" double precision,
383
    "Classification" text,
384
    "Allow partial matches?" boolean,
385
    "Sort by source" boolean,
386
    "Constrain by higher taxonomy" boolean
387
);
388
389
390
--
391
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
392
--
393
394
COMMENT ON TABLE batch_download_settings IS 'stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt';
395
396
397
--
398
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
399
--
400
401
CREATE TABLE client_version (
402
    id text NOT NULL,
403
    global_rev integer NOT NULL,
404
    "/lib/tnrs.py rev" integer,
405
    "/bin/tnrs_db rev" integer
406
);
407
408
409
--
410
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
411
--
412
413
COMMENT ON TABLE client_version IS 'contains svn revisions';
414
415
416
--
417
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
418
--
419
420
COMMENT ON COLUMN client_version.global_rev IS 'from `svn info .` > Last Changed Rev';
421
422
423
--
424
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
425
--
426
427
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS 'from `svn info lib/tnrs.py` > Last Changed Rev';
428
429
430
--
431
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
432
--
433
434
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS 'from `svn info bin/tnrs_db` > Last Changed Rev';
435
436
437
--
438 11964 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
439
--
440
441
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
442
 SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name,
443 13441 aaronmk
    tnrs."Name_matched_rank" AS scrubbed_taxon_rank,
444
    COALESCE(tnrs."Name_matched_accepted_family", tnrs."Family_matched") AS scrubbed_family,
445 11964 aaronmk
    tnrs."Genus_matched" AS scrubbed_genus,
446
    tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet,
447
    tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank,
448
    tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
449 13441 aaronmk
    tnrs."Name_matched_author" AS scrubbed_author,
450
    tnrs."Name_matched" AS scrubbed_taxon_name_no_author
451 11964 aaronmk
   FROM tnrs;
452
453
454
--
455 11965 aaronmk
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
456
--
457
458
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.';
459
460
461
--
462 11964 aaronmk
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
463
--
464
465
CREATE VIEW taxon_scrub AS
466
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
467
    "ValidMatchedTaxon"."*Name_matched.batch",
468
    "ValidMatchedTaxon"."concatenatedScientificName",
469
    "ValidMatchedTaxon"."matchedTaxonName",
470
    "ValidMatchedTaxon"."matchedTaxonRank",
471
    "ValidMatchedTaxon"."*Name_matched.Name_score",
472
    "ValidMatchedTaxon"."matchedScientificNameAuthorship",
473
    "ValidMatchedTaxon"."matchedScientificNameID",
474
    "ValidMatchedTaxon"."*Name_matched.Author_score",
475
    "ValidMatchedTaxon"."matchedFamilyConfidence_fraction",
476
    "ValidMatchedTaxon"."matchedFamily",
477
    "ValidMatchedTaxon"."matchedGenus",
478
    "ValidMatchedTaxon"."matchedGenusConfidence_fraction",
479
    "ValidMatchedTaxon"."matchedSpecificEpithet",
480
    "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction",
481
    "ValidMatchedTaxon"."matchedInfraspecificEpithet",
482
    "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score",
483
    "ValidMatchedTaxon"."identificationQualifier",
484
    "ValidMatchedTaxon"."morphospeciesSuffix",
485
    "ValidMatchedTaxon"."taxonomicStatus",
486 13441 aaronmk
    "ValidMatchedTaxon".accepted_taxon_name_no_author,
487
    "ValidMatchedTaxon".accepted_author,
488
    "ValidMatchedTaxon".accepted_taxon_rank,
489 11964 aaronmk
    "ValidMatchedTaxon"."acceptedScientificNameID",
490 13444 aaronmk
    "ValidMatchedTaxon".accepted_species_binomial,
491 13441 aaronmk
    "ValidMatchedTaxon".accepted_family,
492 11964 aaronmk
    "ValidMatchedTaxon"."*Name_matched.Selected",
493
    "ValidMatchedTaxon"."*Name_matched.Source",
494
    "ValidMatchedTaxon"."*Name_matched.Warnings",
495
    "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid",
496
    "ValidMatchedTaxon".taxon_scrub__is_valid_match,
497 13498 aaronmk
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
498 13441 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
499
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
500 11964 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
501
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
502
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
503
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
504 13441 aaronmk
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
505
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author
506 11964 aaronmk
   FROM ("ValidMatchedTaxon"
507
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
508
509
510
--
511
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
512
--
513
514 13443 aaronmk
COMMENT ON VIEW taxon_scrub IS '
515
to update, use * as the column list
516
';
517 11964 aaronmk
518
519
--
520 10778 aaronmk
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
521
--
522
523
ALTER TABLE ONLY batch_download_settings
524
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
525
526
527
--
528
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
529
--
530
531
ALTER TABLE ONLY batch
532
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
533
534
535
--
536
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
537
--
538
539
ALTER TABLE ONLY batch
540
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
541
542
543
--
544
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
545
--
546
547
ALTER TABLE ONLY client_version
548
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
549
550
551
--
552
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
553
--
554
555
ALTER TABLE ONLY tnrs
556
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
557
558
559
--
560
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
561
--
562
563
ALTER TABLE ONLY tnrs
564
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
565
566
567
--
568 10793 aaronmk
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
569
--
570
571
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
572
573
574
--
575 11607 aaronmk
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
576
--
577
578
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
579
580
581
--
582 10778 aaronmk
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
583
--
584
585
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
586
587
588
--
589
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
590
--
591
592
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
593
594
595
--
596
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
597
--
598
599
ALTER TABLE ONLY batch
600
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
601
602
603
--
604
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
605
--
606
607
ALTER TABLE ONLY batch_download_settings
608
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
609
610
611
--
612
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
613
--
614
615
ALTER TABLE ONLY tnrs
616
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
617
618
619
--
620
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
621
--
622
623
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
624
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
625
GRANT ALL ON SCHEMA "TNRS" TO bien;
626
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
627
628
629
--
630
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
631
--
632
633
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
634
REVOKE ALL ON TABLE tnrs FROM bien;
635
GRANT ALL ON TABLE tnrs TO bien;
636
GRANT SELECT ON TABLE tnrs TO bien_read;
637
638
639
--
640 11912 aaronmk
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
641
--
642
643
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
644
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
645
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
646
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
647
648
649
--
650
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
651
--
652
653
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
654
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
655
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
656
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
657
658
659
--
660
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
661
--
662
663
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
664
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
665
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
666
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
667
668
669
--
670
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
671
--
672
673
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
674
REVOKE ALL ON TABLE taxon_scrub FROM bien;
675
GRANT ALL ON TABLE taxon_scrub TO bien;
676
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
677
678
679
--
680 10778 aaronmk
-- PostgreSQL database dump complete
681
--