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 13575 aaronmk
COMMENT ON SCHEMA "TNRS" IS '
24
IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
25 11617 aaronmk
on vegbiendev:
26
# back up existing TNRS schema (in case of an accidental incorrect change):
27 11614 aaronmk
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
28 11616 aaronmk
$ svn up
29
$ svn di
30
# make the changes shown in the diff
31
## to change column types:
32 13861 aaronmk
SELECT util.set_col_types(''"TNRS".taxon_match'', ARRAY[
33 11614 aaronmk
  (''col'', ''new_type'')
34 11616 aaronmk
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
35 11617 aaronmk
$ rm=1 inputs/.TNRS/schema.sql.run
36
# repeat until `svn di` shows no diff
37
# back up new TNRS schema:
38 13575 aaronmk
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
39
';
40 11614 aaronmk
41
42 10778 aaronmk
SET search_path = "TNRS", pg_catalog;
43
44
--
45
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
46
--
47
48
CREATE FUNCTION batch__fill() RETURNS trigger
49
    LANGUAGE plpgsql
50
    AS $$
51 10728 aaronmk
BEGIN
52
	new.id_by_time = new.time_submitted;
53
	new.id = COALESCE(new.id, new.id_by_time);
54
	RETURN new;
55
END;
56 10778 aaronmk
$$;
57 10728 aaronmk
58
59
--
60 10778 aaronmk
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
61
--
62 10728 aaronmk
63 10778 aaronmk
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
64
    LANGUAGE sql STABLE STRICT
65
    AS $_$
66
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
67
$_$;
68 10736 aaronmk
69 10778 aaronmk
70 10736 aaronmk
--
71 10778 aaronmk
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
72
--
73 10736 aaronmk
74 10778 aaronmk
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
75
    LANGUAGE sql STABLE STRICT
76
    AS $_$
77
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
78
$_$;
79 7844 aaronmk
80 9985 aaronmk
81 10778 aaronmk
--
82 11709 aaronmk
-- Name: map_taxonomic_status(text, text); Type: FUNCTION; Schema: TNRS; Owner: -
83
--
84
85 13503 aaronmk
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
86 11709 aaronmk
    LANGUAGE sql IMMUTABLE
87
    AS $_$
88 13503 aaronmk
/* from http://wiki.vegpath.org/2013-11-14_conference_call#taxonomic-fields:
89
"taxonomic_status should be accepted instead of synonym when an accepted name is
90
available (this is not always the case when a name is marked as a synonym)" */
91 11709 aaronmk
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
92
$_$;
93
94
95
--
96 13868 aaronmk
-- Name: taxon_match__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
97 13866 aaronmk
--
98
99 13868 aaronmk
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
100 13866 aaronmk
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103 13869 aaronmk
	PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
104 13567 aaronmk
	RETURN NULL;
105
END;
106
$$;
107
108
109
--
110 13868 aaronmk
-- Name: taxon_match__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
111 13578 aaronmk
--
112
113 13868 aaronmk
CREATE FUNCTION taxon_match__fill() RETURNS trigger
114 13578 aaronmk
    LANGUAGE plpgsql
115
    AS $$
116 11643 aaronmk
BEGIN
117 13871 aaronmk
	DECLARE
118
		"Specific_epithet_is_plant" boolean :=
119 11628 aaronmk
			(CASE
120 14111 aaronmk
			WHEN   new."*Infraspecific_epithet_matched"	 IS NOT NULL
121
				OR new."*Infraspecific_epithet_2_matched" IS NOT NULL
122
				OR new."*Specific_epithet_score" >= 0.9 -- fuzzy match
123 13871 aaronmk
				THEN true
124
			ELSE NULL -- ambiguous
125
			END);
126 14111 aaronmk
		never_homonym boolean = COALESCE(new."*Author_score" >= 0.6, false);
127 13871 aaronmk
			-- author disambiguates
128
		family_is_homonym boolean = NOT never_homonym
129 14111 aaronmk
			AND "TNRS".family_is_homonym(new."*Family_matched");
130 13871 aaronmk
		genus_is_homonym  boolean = NOT never_homonym
131 14111 aaronmk
			AND "TNRS".genus_is_homonym(new."*Genus_matched");
132 13871 aaronmk
	BEGIN
133
		/* exclude homonyms because these are not valid matches (TNRS provides a
134
		name, but the name is not meaningful because it is not unambiguous) */
135 14111 aaronmk
		new.is_valid_match = new."*Taxonomic_status" != 'Invalid'
136 13871 aaronmk
			AND COALESCE(CASE
137 14111 aaronmk
			WHEN new."*Family_score" = 1 AND NOT family_is_homonym -- exact match
138 13871 aaronmk
				THEN true
139
			ELSE -- consider genus
140 11628 aaronmk
				(CASE
141 14111 aaronmk
				WHEN new."*Genus_score" =  1	   -- exact match
142 13871 aaronmk
					THEN
143
					(CASE
144
					WHEN NOT genus_is_homonym THEN true
145
					ELSE "Specific_epithet_is_plant"
146
					END)
147 14111 aaronmk
				WHEN new."*Genus_score" >= 0.85 -- fuzzy match
148 13871 aaronmk
					THEN "Specific_epithet_is_plant"
149
				ELSE NULL -- ambiguous
150 11628 aaronmk
				END)
151 13871 aaronmk
			END, false);
152
	END;
153 11628 aaronmk
154 13871 aaronmk
	DECLARE
155
		matched_taxon_name_with_author text = NULLIF(concat_ws(' '
156 14111 aaronmk
			, 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 13871 aaronmk
			), '');
161
		accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
162 14111 aaronmk
			, NULLIF(NULLIF(new."*Accepted_name_family", 'Unknown'),
163
				new."*Accepted_name")
164
			, new."*Accepted_name"
165
			, new."*Accepted_name_author"
166 13871 aaronmk
			), '');
167
	BEGIN
168
		new.scrubbed_unique_taxon_name = COALESCE(
169
			accepted_taxon_name_with_author, matched_taxon_name_with_author);
170
	END;
171
172 11628 aaronmk
	RETURN new;
173 7134 aaronmk
END;
174 10778 aaronmk
$$;
175
176
177
--
178 13868 aaronmk
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
179 10778 aaronmk
--
180
181 13868 aaronmk
COMMENT ON FUNCTION taxon_match__fill() IS '
182 13575 aaronmk
IMPORTANT: when changing this function, you must regenerate the derived cols:
183 13861 aaronmk
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
184 11715 aaronmk
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
185 13861 aaronmk
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
186 13575 aaronmk
runtime: 1.5 min ("92633 ms")
187
';
188 7134 aaronmk
189 7251 aaronmk
190 13631 aaronmk
--
191 14122 aaronmk
-- Name: taxon_match__fill_derived(); Type: FUNCTION; Schema: TNRS; Owner: -
192
--
193
194
CREATE FUNCTION taxon_match__fill_derived() RETURNS trigger
195
    LANGUAGE plpgsql
196
    AS $$
197
BEGIN
198
	new."__accepted_{genus,specific_epithet}" = (SELECT
199
		regexp_split_to_array("*Accepted_name_species", ' ')
200
		FROM (SELECT new.*) new);
201
202
	RETURN new;
203
END;
204
$$;
205
206
207
--
208 13868 aaronmk
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
209
--
210
211
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
212
    LANGUAGE plpgsql
213
    AS $$
214
BEGIN
215
	IF new.match_num IS NULL THEN
216 13869 aaronmk
		new.match_num = "TNRS".taxon_match__match_num__next();
217 13868 aaronmk
	END IF;
218
	RETURN new;
219
END;
220
$$;
221
222
223
--
224 13869 aaronmk
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
225
--
226
227
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
228
    LANGUAGE sql
229
    AS $$
230
SELECT nextval('pg_temp.taxon_match__match_num__seq');
231
$$;
232
233
234
--
235 13868 aaronmk
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
236
--
237
238
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
239
    LANGUAGE plpgsql
240
    AS $$
241
BEGIN
242
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
243
	RETURN NULL;
244
END;
245
$$;
246
247
248
--
249
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
250
--
251
252
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
253
    LANGUAGE sql IMMUTABLE
254
    AS $_$
255
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
256
$_$;
257
258
259
--
260 13631 aaronmk
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
261
--
262
263
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
264
    LANGUAGE sql IMMUTABLE
265
    AS $$
266
SELECT ARRAY[
267 13686 aaronmk
]::text[]
268 13631 aaronmk
$$;
269
270
271 10778 aaronmk
SET default_tablespace = '';
272
273
SET default_with_oids = false;
274
275 10728 aaronmk
--
276 13861 aaronmk
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
277 10778 aaronmk
--
278 7251 aaronmk
279 13861 aaronmk
CREATE TABLE taxon_match (
280 10778 aaronmk
    batch text DEFAULT now() NOT NULL,
281 13580 aaronmk
    match_num integer NOT NULL,
282 14111 aaronmk
    "*Name_number" integer NOT NULL,
283
    "*Name_submitted" text NOT NULL,
284
    "*Overall_score" double precision,
285
    "*Name_matched" text,
286
    "*Name_matched_rank" text,
287
    "*Name_score" double precision,
288
    "*Name_matched_author" text,
289
    "*Name_matched_url" text,
290
    "*Author_matched" text,
291
    "*Author_score" double precision,
292
    "*Family_matched" text,
293
    "*Family_score" double precision,
294
    "*Name_matched_accepted_family" text,
295
    "*Genus_matched" text,
296
    "*Genus_score" double precision,
297
    "*Specific_epithet_matched" text,
298
    "*Specific_epithet_score" double precision,
299
    "*Infraspecific_rank" text,
300
    "*Infraspecific_epithet_matched" text,
301
    "*Infraspecific_epithet_score" double precision,
302
    "*Infraspecific_rank_2" text,
303
    "*Infraspecific_epithet_2_matched" text,
304
    "*Infraspecific_epithet_2_score" double precision,
305
    "*Annotations" text,
306
    "*Unmatched_terms" text,
307
    "*Taxonomic_status" text,
308
    "*Accepted_name" text,
309
    "*Accepted_name_author" text,
310
    "*Accepted_name_rank" text,
311
    "*Accepted_name_url" text,
312
    "*Accepted_name_species" text,
313
    "*Accepted_name_family" text,
314
    "*Selected" text,
315
    "*Source" text,
316
    "*Warnings" text,
317
    "*Accepted_name_lsid" text,
318 11628 aaronmk
    is_valid_match boolean NOT NULL,
319 14122 aaronmk
    scrubbed_unique_taxon_name text,
320
    "__accepted_{genus,specific_epithet}" text[],
321
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text))))
322 10778 aaronmk
);
323 7823 aaronmk
324 9759 aaronmk
325 10778 aaronmk
--
326 13861 aaronmk
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
327 10778 aaronmk
--
328 7823 aaronmk
329 13861 aaronmk
COMMENT ON TABLE taxon_match IS '
330 13577 aaronmk
to remove columns or add columns at the end:
331
$ rm=1 inputs/.TNRS/data.sql.run
332
$ make schemas/remake
333
334
to add columns in the middle:
335
make the changes in inputs/.TNRS/schema.sql
336
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
337
$ make schemas/remake
338 13582 aaronmk
339
to populate a new column:
340 13868 aaronmk
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
341 13861 aaronmk
UPDATE "TNRS".taxon_match SET "col" = value;
342 13582 aaronmk
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
343 13868 aaronmk
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
344 13861 aaronmk
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
345 13584 aaronmk
346
to add a constraint: runtime: 3 min ("173620 ms")
347 13575 aaronmk
';
348 10778 aaronmk
349
350
--
351 13878 aaronmk
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
352
--
353
354
CREATE VIEW taxon_best_match AS
355
 SELECT taxon_match.batch,
356
    taxon_match.match_num,
357 14111 aaronmk
    taxon_match."*Name_number",
358
    taxon_match."*Name_submitted",
359
    taxon_match."*Overall_score",
360
    taxon_match."*Name_matched",
361
    taxon_match."*Name_matched_rank",
362
    taxon_match."*Name_score",
363
    taxon_match."*Name_matched_author",
364
    taxon_match."*Name_matched_url",
365
    taxon_match."*Author_matched",
366
    taxon_match."*Author_score",
367
    taxon_match."*Family_matched",
368
    taxon_match."*Family_score",
369
    taxon_match."*Name_matched_accepted_family",
370
    taxon_match."*Genus_matched",
371
    taxon_match."*Genus_score",
372
    taxon_match."*Specific_epithet_matched",
373
    taxon_match."*Specific_epithet_score",
374
    taxon_match."*Infraspecific_rank",
375
    taxon_match."*Infraspecific_epithet_matched",
376
    taxon_match."*Infraspecific_epithet_score",
377
    taxon_match."*Infraspecific_rank_2",
378
    taxon_match."*Infraspecific_epithet_2_matched",
379
    taxon_match."*Infraspecific_epithet_2_score",
380
    taxon_match."*Annotations",
381
    taxon_match."*Unmatched_terms",
382
    taxon_match."*Taxonomic_status",
383
    taxon_match."*Accepted_name",
384
    taxon_match."*Accepted_name_author",
385
    taxon_match."*Accepted_name_rank",
386
    taxon_match."*Accepted_name_url",
387
    taxon_match."*Accepted_name_species",
388
    taxon_match."*Accepted_name_family",
389
    taxon_match."*Selected",
390
    taxon_match."*Source",
391
    taxon_match."*Warnings",
392
    taxon_match."*Accepted_name_lsid",
393 13878 aaronmk
    taxon_match.is_valid_match,
394
    taxon_match.scrubbed_unique_taxon_name
395
   FROM taxon_match
396 14111 aaronmk
  WHERE (taxon_match."*Selected" = 'true'::text);
397 13878 aaronmk
398
399
--
400
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
401
--
402
403
COMMENT ON VIEW taxon_best_match IS '
404
to modify:
405
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
406
SELECT __
407
$$);
408
';
409
410
411
--
412 10778 aaronmk
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
413
--
414
415
CREATE VIEW "MatchedTaxon" AS
416 14110 aaronmk
 SELECT taxon_best_match.batch,
417
    taxon_best_match.match_num,
418 14111 aaronmk
    taxon_best_match."*Name_number",
419
    taxon_best_match."*Name_submitted",
420
    taxon_best_match."*Overall_score",
421
    taxon_best_match."*Name_matched",
422
    taxon_best_match."*Name_matched_rank",
423
    taxon_best_match."*Name_score",
424
    taxon_best_match."*Name_matched_author",
425
    taxon_best_match."*Name_matched_url",
426
    taxon_best_match."*Author_matched",
427
    taxon_best_match."*Author_score",
428
    taxon_best_match."*Family_matched",
429
    taxon_best_match."*Family_score",
430
    taxon_best_match."*Name_matched_accepted_family",
431
    taxon_best_match."*Genus_matched",
432
    taxon_best_match."*Genus_score",
433
    taxon_best_match."*Specific_epithet_matched",
434
    taxon_best_match."*Specific_epithet_score",
435
    taxon_best_match."*Infraspecific_rank",
436
    taxon_best_match."*Infraspecific_epithet_matched",
437
    taxon_best_match."*Infraspecific_epithet_score",
438
    taxon_best_match."*Infraspecific_rank_2",
439
    taxon_best_match."*Infraspecific_epithet_2_matched",
440
    taxon_best_match."*Infraspecific_epithet_2_score",
441
    taxon_best_match."*Annotations",
442
    taxon_best_match."*Unmatched_terms",
443
    taxon_best_match."*Taxonomic_status",
444
    taxon_best_match."*Accepted_name",
445
    taxon_best_match."*Accepted_name_author",
446
    taxon_best_match."*Accepted_name_rank",
447
    taxon_best_match."*Accepted_name_url",
448
    taxon_best_match."*Accepted_name_species",
449
    taxon_best_match."*Accepted_name_family",
450
    taxon_best_match."*Selected",
451
    taxon_best_match."*Source",
452
    taxon_best_match."*Warnings",
453
    taxon_best_match."*Accepted_name_lsid",
454 14110 aaronmk
    taxon_best_match.is_valid_match,
455
    taxon_best_match.scrubbed_unique_taxon_name,
456 14111 aaronmk
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
457 13498 aaronmk
        CASE
458 14111 aaronmk
            WHEN (taxon_best_match."*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name_family", taxon_best_match."*Unmatched_terms")
459
            WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
460
            ELSE taxon_best_match."*Accepted_name_species"
461 13498 aaronmk
        END AS accepted_morphospecies_binomial
462 14110 aaronmk
   FROM taxon_best_match;
463 10778 aaronmk
464
465
--
466 13498 aaronmk
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
467
--
468
469
COMMENT ON VIEW "MatchedTaxon" IS '
470 13501 aaronmk
to modify:
471 13845 aaronmk
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
472 13647 aaronmk
SELECT __
473 13501 aaronmk
$$);
474 13498 aaronmk
';
475
476
477
--
478 10778 aaronmk
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
479
--
480
481
CREATE VIEW "ValidMatchedTaxon" AS
482 14108 aaronmk
 SELECT "MatchedTaxon".batch,
483 14105 aaronmk
    "MatchedTaxon".match_num,
484 14111 aaronmk
    "MatchedTaxon"."*Name_number",
485
    "MatchedTaxon"."*Name_submitted",
486
    "MatchedTaxon"."*Overall_score",
487
    "MatchedTaxon"."*Name_matched",
488
    "MatchedTaxon"."*Name_matched_rank",
489
    "MatchedTaxon"."*Name_score",
490
    "MatchedTaxon"."*Name_matched_author",
491
    "MatchedTaxon"."*Name_matched_url",
492
    "MatchedTaxon"."*Author_matched",
493
    "MatchedTaxon"."*Author_score",
494
    "MatchedTaxon"."*Family_matched",
495
    "MatchedTaxon"."*Family_score",
496
    "MatchedTaxon"."*Name_matched_accepted_family",
497
    "MatchedTaxon"."*Genus_matched",
498
    "MatchedTaxon"."*Genus_score",
499
    "MatchedTaxon"."*Specific_epithet_matched",
500
    "MatchedTaxon"."*Specific_epithet_score",
501
    "MatchedTaxon"."*Infraspecific_rank",
502
    "MatchedTaxon"."*Infraspecific_epithet_matched",
503
    "MatchedTaxon"."*Infraspecific_epithet_score",
504
    "MatchedTaxon"."*Infraspecific_rank_2",
505
    "MatchedTaxon"."*Infraspecific_epithet_2_matched",
506
    "MatchedTaxon"."*Infraspecific_epithet_2_score",
507
    "MatchedTaxon"."*Annotations",
508
    "MatchedTaxon"."*Unmatched_terms",
509
    "MatchedTaxon"."*Taxonomic_status",
510
    "MatchedTaxon"."*Accepted_name",
511
    "MatchedTaxon"."*Accepted_name_author",
512
    "MatchedTaxon"."*Accepted_name_rank",
513
    "MatchedTaxon"."*Accepted_name_url",
514
    "MatchedTaxon"."*Accepted_name_species",
515
    "MatchedTaxon"."*Accepted_name_family",
516
    "MatchedTaxon"."*Selected",
517
    "MatchedTaxon"."*Source",
518
    "MatchedTaxon"."*Warnings",
519
    "MatchedTaxon"."*Accepted_name_lsid",
520 14108 aaronmk
    "MatchedTaxon".is_valid_match,
521 13800 aaronmk
    "MatchedTaxon".scrubbed_unique_taxon_name,
522 14103 aaronmk
    "MatchedTaxon"."taxonomicStatus",
523 13498 aaronmk
    "MatchedTaxon".accepted_morphospecies_binomial
524 11708 aaronmk
   FROM "MatchedTaxon"
525 14108 aaronmk
  WHERE "MatchedTaxon".is_valid_match;
526 10778 aaronmk
527
528
--
529
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
530
--
531
532 13443 aaronmk
COMMENT ON VIEW "ValidMatchedTaxon" IS '
533
to update, use * as the column list
534
';
535 10778 aaronmk
536
537
--
538
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
539
--
540
541
CREATE TABLE batch (
542
    id text NOT NULL,
543
    id_by_time text,
544
    time_submitted timestamp with time zone DEFAULT now(),
545
    client_version text
546
);
547
548
549
--
550
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
551
--
552
553
CREATE TABLE batch_download_settings (
554
    id text NOT NULL,
555
    "E-mail" text,
556
    "Id" text,
557
    "Job type" text,
558
    "Contains Id" boolean,
559
    "Start time" text,
560
    "Finish time" text,
561
    "TNRS version" text,
562
    "Sources selected" text,
563
    "Match threshold" double precision,
564
    "Classification" text,
565
    "Allow partial matches?" boolean,
566
    "Sort by source" boolean,
567
    "Constrain by higher taxonomy" boolean
568
);
569
570
571
--
572
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
573
--
574
575 13575 aaronmk
COMMENT ON TABLE batch_download_settings IS '
576
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
577
';
578 10778 aaronmk
579
580
--
581
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
582
--
583
584
CREATE TABLE client_version (
585
    id text NOT NULL,
586
    global_rev integer NOT NULL,
587
    "/lib/tnrs.py rev" integer,
588
    "/bin/tnrs_db rev" integer
589
);
590
591
592
--
593
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
594
--
595
596 13575 aaronmk
COMMENT ON TABLE client_version IS '
597
contains svn revisions
598
';
599 10778 aaronmk
600
601
--
602
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
603
--
604
605 13575 aaronmk
COMMENT ON COLUMN client_version.global_rev IS '
606
from `svn info .` > Last Changed Rev
607
';
608 10778 aaronmk
609
610
--
611
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
612
--
613
614 13575 aaronmk
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
615
from `svn info lib/tnrs.py` > Last Changed Rev
616
';
617 10778 aaronmk
618
619
--
620
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
621
--
622
623 13575 aaronmk
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
624
from `svn info bin/tnrs_db` > Last Changed Rev
625
';
626 10778 aaronmk
627
628
--
629 13866 aaronmk
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
630
--
631
632
CREATE VIEW taxon_match_input AS
633 14111 aaronmk
 SELECT taxon_match."*Name_number" AS "Name_number",
634
    taxon_match."*Name_submitted" AS "Name_submitted",
635
    taxon_match."*Overall_score" AS "Overall_score",
636
    taxon_match."*Name_matched" AS "Name_matched",
637
    taxon_match."*Name_matched_rank" AS "Name_matched_rank",
638
    taxon_match."*Name_score" AS "Name_score",
639
    taxon_match."*Name_matched_author" AS "Name_matched_author",
640
    taxon_match."*Name_matched_url" AS "Name_matched_url",
641
    taxon_match."*Author_matched" AS "Author_matched",
642
    taxon_match."*Author_score" AS "Author_score",
643
    taxon_match."*Family_matched" AS "Family_matched",
644
    taxon_match."*Family_score" AS "Family_score",
645
    taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
646
    taxon_match."*Genus_matched" AS "Genus_matched",
647
    taxon_match."*Genus_score" AS "Genus_score",
648
    taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
649
    taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
650
    taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
651
    taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
652
    taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
653
    taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
654
    taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
655
    taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
656
    taxon_match."*Annotations" AS "Annotations",
657
    taxon_match."*Unmatched_terms" AS "Unmatched_terms",
658
    taxon_match."*Taxonomic_status" AS "Taxonomic_status",
659
    taxon_match."*Accepted_name" AS "Accepted_name",
660
    taxon_match."*Accepted_name_author" AS "Accepted_name_author",
661
    taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
662
    taxon_match."*Accepted_name_url" AS "Accepted_name_url",
663
    taxon_match."*Accepted_name_species" AS "Accepted_name_species",
664
    taxon_match."*Accepted_name_family" AS "Accepted_name_family",
665
    taxon_match."*Selected" AS "Selected",
666
    taxon_match."*Source" AS "Source",
667
    taxon_match."*Warnings" AS "Warnings",
668
    taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
669 13866 aaronmk
   FROM taxon_match;
670
671
672
--
673
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
674
--
675
676
CREATE TABLE taxon_match_input__copy_to (
677
    "Name_number" integer,
678
    "Name_submitted" text,
679
    "Overall_score" double precision,
680
    "Name_matched" text,
681
    "Name_matched_rank" text,
682
    "Name_score" double precision,
683
    "Name_matched_author" text,
684
    "Name_matched_url" text,
685
    "Author_matched" text,
686
    "Author_score" double precision,
687
    "Family_matched" text,
688
    "Family_score" double precision,
689
    "Name_matched_accepted_family" text,
690
    "Genus_matched" text,
691
    "Genus_score" double precision,
692
    "Specific_epithet_matched" text,
693
    "Specific_epithet_score" double precision,
694
    "Infraspecific_rank" text,
695
    "Infraspecific_epithet_matched" text,
696
    "Infraspecific_epithet_score" double precision,
697
    "Infraspecific_rank_2" text,
698
    "Infraspecific_epithet_2_matched" text,
699
    "Infraspecific_epithet_2_score" double precision,
700
    "Annotations" text,
701
    "Unmatched_terms" text,
702
    "Taxonomic_status" text,
703
    "Accepted_name" text,
704
    "Accepted_name_author" text,
705
    "Accepted_name_rank" text,
706
    "Accepted_name_url" text,
707
    "Accepted_name_species" text,
708
    "Accepted_name_family" text,
709
    "Selected" text,
710
    "Source" text,
711
    "Warnings" text,
712
    "Accepted_name_lsid" text
713
);
714
715
716
--
717 11964 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
718
--
719
720
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
721 14111 aaronmk
 SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
722
    taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
723
    COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
724
    taxon_match."*Genus_matched" AS scrubbed_genus,
725
    taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
726
    taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
727
    taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
728
    taxon_match."*Name_matched_author" AS scrubbed_author,
729
    taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
730
    (taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
731 13861 aaronmk
   FROM taxon_match;
732 11964 aaronmk
733
734
--
735 11965 aaronmk
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
736
--
737
738 13575 aaronmk
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
739 13846 aaronmk
to modify:
740
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
741
SELECT __
742
$$);
743
744 13575 aaronmk
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.
745
';
746 11965 aaronmk
747
748
--
749 11964 aaronmk
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
750
--
751
752
CREATE VIEW taxon_scrub AS
753 13800 aaronmk
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
754 14108 aaronmk
    "ValidMatchedTaxon".batch,
755 14105 aaronmk
    "ValidMatchedTaxon".match_num,
756 14111 aaronmk
    "ValidMatchedTaxon"."*Name_number",
757
    "ValidMatchedTaxon"."*Name_submitted",
758
    "ValidMatchedTaxon"."*Overall_score",
759
    "ValidMatchedTaxon"."*Name_matched",
760
    "ValidMatchedTaxon"."*Name_matched_rank",
761
    "ValidMatchedTaxon"."*Name_score",
762
    "ValidMatchedTaxon"."*Name_matched_author",
763
    "ValidMatchedTaxon"."*Name_matched_url",
764
    "ValidMatchedTaxon"."*Author_matched",
765
    "ValidMatchedTaxon"."*Author_score",
766
    "ValidMatchedTaxon"."*Family_matched",
767
    "ValidMatchedTaxon"."*Family_score",
768
    "ValidMatchedTaxon"."*Name_matched_accepted_family",
769
    "ValidMatchedTaxon"."*Genus_matched",
770
    "ValidMatchedTaxon"."*Genus_score",
771
    "ValidMatchedTaxon"."*Specific_epithet_matched",
772
    "ValidMatchedTaxon"."*Specific_epithet_score",
773
    "ValidMatchedTaxon"."*Infraspecific_rank",
774
    "ValidMatchedTaxon"."*Infraspecific_epithet_matched",
775
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
776
    "ValidMatchedTaxon"."*Infraspecific_rank_2",
777
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
778
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
779
    "ValidMatchedTaxon"."*Annotations",
780
    "ValidMatchedTaxon"."*Unmatched_terms",
781
    "ValidMatchedTaxon"."*Taxonomic_status",
782
    "ValidMatchedTaxon"."*Accepted_name",
783
    "ValidMatchedTaxon"."*Accepted_name_author",
784
    "ValidMatchedTaxon"."*Accepted_name_rank",
785
    "ValidMatchedTaxon"."*Accepted_name_url",
786
    "ValidMatchedTaxon"."*Accepted_name_species",
787
    "ValidMatchedTaxon"."*Accepted_name_family",
788
    "ValidMatchedTaxon"."*Selected",
789
    "ValidMatchedTaxon"."*Source",
790
    "ValidMatchedTaxon"."*Warnings",
791
    "ValidMatchedTaxon"."*Accepted_name_lsid",
792 14108 aaronmk
    "ValidMatchedTaxon".is_valid_match,
793 14103 aaronmk
    "ValidMatchedTaxon"."taxonomicStatus",
794 13800 aaronmk
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
795
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
796
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
797
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
798
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
799
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
800
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
801
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
802
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
803
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
804 13532 aaronmk
        CASE
805 14111 aaronmk
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'family'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "ValidMatchedTaxon"."*Unmatched_terms")
806
            WHEN ("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank = 'genus'::text) THEN concat_ws(' '::text, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author, "ValidMatchedTaxon"."*Unmatched_terms")
807 13532 aaronmk
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
808
        END AS scrubbed_morphospecies_binomial
809 11964 aaronmk
   FROM ("ValidMatchedTaxon"
810
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
811
812
813
--
814
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
815
--
816
817 13443 aaronmk
COMMENT ON VIEW taxon_scrub IS '
818 13531 aaronmk
to modify:
819 13845 aaronmk
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
820 13647 aaronmk
SELECT __
821 13531 aaronmk
$$);
822 13443 aaronmk
';
823 11964 aaronmk
824
825
--
826 10778 aaronmk
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
827
--
828
829
ALTER TABLE ONLY batch_download_settings
830
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
831
832
833
--
834
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
835
--
836
837
ALTER TABLE ONLY batch
838
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
839
840
841
--
842
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
843
--
844
845
ALTER TABLE ONLY batch
846
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
847
848
849
--
850
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
851
--
852
853
ALTER TABLE ONLY client_version
854
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
855
856
857
--
858 13868 aaronmk
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
859 10778 aaronmk
--
860
861 13861 aaronmk
ALTER TABLE ONLY taxon_match
862 13868 aaronmk
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
863 10778 aaronmk
864 14125 aaronmk
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
865 10778 aaronmk
866 14125 aaronmk
867 10778 aaronmk
--
868 10793 aaronmk
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
869
--
870
871
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
872
873
874
--
875 13879 aaronmk
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
876 13589 aaronmk
--
877
878 14111 aaronmk
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
879 13589 aaronmk
880
881
--
882 13879 aaronmk
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
883 13874 aaronmk
--
884
885 14111 aaronmk
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
886 13874 aaronmk
887
888
--
889 13879 aaronmk
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
890 11607 aaronmk
--
891
892 14111 aaronmk
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
893 11607 aaronmk
894
895
--
896 10778 aaronmk
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
897
--
898
899
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
900
901
902
--
903 13868 aaronmk
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
904 13866 aaronmk
--
905
906 13868 aaronmk
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
907 13866 aaronmk
908
909
--
910 13868 aaronmk
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
911 13567 aaronmk
--
912
913 13868 aaronmk
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
914 13567 aaronmk
915
916
--
917 14122 aaronmk
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
918
--
919
920
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
921
922
923
--
924 13868 aaronmk
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
925 13578 aaronmk
--
926
927 13868 aaronmk
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
928 13578 aaronmk
929
930
--
931 13868 aaronmk
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
932 10778 aaronmk
--
933
934 13868 aaronmk
CREATE TRIGGER taxon_match_input__copy_to__insert BEFORE INSERT ON taxon_match_input__copy_to FOR EACH ROW EXECUTE PROCEDURE taxon_match_input__copy_to__insert();
935 10778 aaronmk
936
937
--
938
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
939
--
940
941
ALTER TABLE ONLY batch
942
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
943
944
945
--
946
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
947
--
948
949
ALTER TABLE ONLY batch_download_settings
950
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
951
952
953
--
954 13868 aaronmk
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
955 10778 aaronmk
--
956
957 13861 aaronmk
ALTER TABLE ONLY taxon_match
958 13868 aaronmk
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
959 10778 aaronmk
960
961
--
962
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
963
--
964
965
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
966
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
967
GRANT ALL ON SCHEMA "TNRS" TO bien;
968
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
969
970
971
--
972 13861 aaronmk
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
973 10778 aaronmk
--
974
975 13861 aaronmk
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
976
REVOKE ALL ON TABLE taxon_match FROM bien;
977
GRANT ALL ON TABLE taxon_match TO bien;
978
GRANT SELECT ON TABLE taxon_match TO bien_read;
979 10778 aaronmk
980
981
--
982 13878 aaronmk
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
983
--
984
985
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
986
REVOKE ALL ON TABLE taxon_best_match FROM bien;
987
GRANT ALL ON TABLE taxon_best_match TO bien;
988
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
989
990
991
--
992 11912 aaronmk
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
993
--
994
995
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
996
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
997
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
998
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
999
1000
1001
--
1002
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1003
--
1004
1005
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1006
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1007
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1008
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1009
1010
1011
--
1012 13866 aaronmk
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1013
--
1014
1015
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1016
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1017
GRANT ALL ON TABLE taxon_match_input TO bien;
1018
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1019
1020
1021
--
1022 11912 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1023
--
1024
1025
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1026
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1027
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1028
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1029
1030
1031
--
1032
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1033
--
1034
1035
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1036
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1037
GRANT ALL ON TABLE taxon_scrub TO bien;
1038
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1039
1040
1041
--
1042 10778 aaronmk
-- PostgreSQL database dump complete
1043
--