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 14150 aaronmk
		regexp_split_to_array("*Accepted_name_species", ' '::text)
200 14122 aaronmk
		FROM (SELECT new.*) new);
201
202 14257 aaronmk
	new."[accepted_]genus__@DwC__@vegpath.org" = (SELECT
203
		"__accepted_{genus,specific_epithet}"[1]
204
		FROM (SELECT new.*) new);
205
206
	new."[accepted_]specificEpithet__@DwC__@vegpath.org" = (SELECT
207
		"__accepted_{genus,specific_epithet}"[2]
208
		FROM (SELECT new.*) new);
209
210 14122 aaronmk
	RETURN new;
211
END;
212
$$;
213
214
215
--
216 14254 aaronmk
-- Name: FUNCTION taxon_match__fill_derived(); Type: COMMENT; Schema: TNRS; Owner: -
217
--
218
219
COMMENT ON FUNCTION taxon_match__fill_derived() IS '
220
autogenerated, do not edit
221
222
to regenerate:
223
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
224
';
225
226
227
--
228 13868 aaronmk
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
229
--
230
231
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
232
    LANGUAGE plpgsql
233
    AS $$
234
BEGIN
235
	IF new.match_num IS NULL THEN
236 13869 aaronmk
		new.match_num = "TNRS".taxon_match__match_num__next();
237 13868 aaronmk
	END IF;
238
	RETURN new;
239
END;
240
$$;
241
242
243
--
244 13869 aaronmk
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
245
--
246
247
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
248
    LANGUAGE sql
249
    AS $$
250
SELECT nextval('pg_temp.taxon_match__match_num__seq');
251
$$;
252
253
254
--
255 13868 aaronmk
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
256
--
257
258
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
259
    LANGUAGE plpgsql
260
    AS $$
261
BEGIN
262
	INSERT INTO "TNRS".taxon_match_input SELECT new.*;
263
	RETURN NULL;
264
END;
265
$$;
266
267
268
--
269
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
270
--
271
272
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
273
    LANGUAGE sql IMMUTABLE
274
    AS $_$
275
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
276
$_$;
277
278
279
--
280 13631 aaronmk
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
281
--
282
283
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
284
    LANGUAGE sql IMMUTABLE
285
    AS $$
286
SELECT ARRAY[
287 13686 aaronmk
]::text[]
288 13631 aaronmk
$$;
289
290
291 10778 aaronmk
SET default_tablespace = '';
292
293
SET default_with_oids = false;
294
295 10728 aaronmk
--
296 13861 aaronmk
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
297 10778 aaronmk
--
298 7251 aaronmk
299 13861 aaronmk
CREATE TABLE taxon_match (
300 10778 aaronmk
    batch text DEFAULT now() NOT NULL,
301 13580 aaronmk
    match_num integer NOT NULL,
302 14111 aaronmk
    "*Name_number" integer NOT NULL,
303
    "*Name_submitted" text NOT NULL,
304
    "*Overall_score" double precision,
305
    "*Name_matched" text,
306
    "*Name_matched_rank" text,
307
    "*Name_score" double precision,
308
    "*Name_matched_author" text,
309
    "*Name_matched_url" text,
310
    "*Author_matched" text,
311
    "*Author_score" double precision,
312
    "*Family_matched" text,
313
    "*Family_score" double precision,
314
    "*Name_matched_accepted_family" text,
315
    "*Genus_matched" text,
316
    "*Genus_score" double precision,
317
    "*Specific_epithet_matched" text,
318
    "*Specific_epithet_score" double precision,
319
    "*Infraspecific_rank" text,
320
    "*Infraspecific_epithet_matched" text,
321
    "*Infraspecific_epithet_score" double precision,
322
    "*Infraspecific_rank_2" text,
323
    "*Infraspecific_epithet_2_matched" text,
324
    "*Infraspecific_epithet_2_score" double precision,
325
    "*Annotations" text,
326
    "*Unmatched_terms" text,
327
    "*Taxonomic_status" text,
328
    "*Accepted_name" text,
329
    "*Accepted_name_author" text,
330
    "*Accepted_name_rank" text,
331
    "*Accepted_name_url" text,
332
    "*Accepted_name_species" text,
333
    "*Accepted_name_family" text,
334
    "*Selected" text,
335
    "*Source" text,
336
    "*Warnings" text,
337
    "*Accepted_name_lsid" text,
338 11628 aaronmk
    is_valid_match boolean NOT NULL,
339 14122 aaronmk
    scrubbed_unique_taxon_name text,
340
    "__accepted_{genus,specific_epithet}" text[],
341 14257 aaronmk
    "[accepted_]genus__@DwC__@vegpath.org" text,
342
    "[accepted_]specificEpithet__@DwC__@vegpath.org" text,
343
    CONSTRAINT "[accepted_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]genus__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[1]))),
344
    CONSTRAINT "[accepted_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[2]))),
345 14122 aaronmk
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text))))
346 10778 aaronmk
);
347 7823 aaronmk
348 9759 aaronmk
349 10778 aaronmk
--
350 13861 aaronmk
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
351 10778 aaronmk
--
352 7823 aaronmk
353 13861 aaronmk
COMMENT ON TABLE taxon_match IS '
354 14161 aaronmk
whenever columns are renamed:
355
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
356
357 13577 aaronmk
to remove columns or add columns at the end:
358
$ rm=1 inputs/.TNRS/data.sql.run
359
$ make schemas/remake
360
361
to add columns in the middle:
362
make the changes in inputs/.TNRS/schema.sql
363
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
364
$ make schemas/remake
365 13582 aaronmk
366
to populate a new column:
367 13868 aaronmk
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
368 13861 aaronmk
UPDATE "TNRS".taxon_match SET "col" = value;
369 13582 aaronmk
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
370 14132 aaronmk
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
371 13868 aaronmk
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
372 13861 aaronmk
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
373 13584 aaronmk
374
to add a constraint: runtime: 3 min ("173620 ms")
375 13575 aaronmk
';
376 10778 aaronmk
377
378
--
379 14254 aaronmk
-- Name: COLUMN taxon_match."__accepted_{genus,specific_epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
380
--
381
382
COMMENT ON COLUMN taxon_match."__accepted_{genus,specific_epithet}" IS '
383
derived column; = regexp_split_to_array("*Accepted_name_species", '' ''::text)
384
385
to modify:
386
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_{genus,specific_epithet}'')::util.col, $$regexp_split_to_array("*Accepted_name_species", '' ''::text)$$)::util.derived_col_def);
387 14258 aaronmk
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
388 14254 aaronmk
';
389
390
391
--
392 14257 aaronmk
-- Name: COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
393
--
394
395
COMMENT ON COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org" IS '
396
derived column; = "__accepted_{genus,specific_epithet}"[1]
397
398
to modify:
399
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]genus__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[1]$$)::util.derived_col_def);
400 14258 aaronmk
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
401 14257 aaronmk
';
402
403
404
--
405
-- Name: COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
406
--
407
408
COMMENT ON COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org" IS '
409
derived column; = "__accepted_{genus,specific_epithet}"[2]
410
411
to modify:
412
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[2]$$)::util.derived_col_def);
413 14258 aaronmk
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
414 14257 aaronmk
';
415
416
417
--
418 13878 aaronmk
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
419
--
420
421
CREATE VIEW taxon_best_match AS
422
 SELECT taxon_match.batch,
423
    taxon_match.match_num,
424 14111 aaronmk
    taxon_match."*Name_number",
425
    taxon_match."*Name_submitted",
426
    taxon_match."*Overall_score",
427
    taxon_match."*Name_matched",
428
    taxon_match."*Name_matched_rank",
429
    taxon_match."*Name_score",
430
    taxon_match."*Name_matched_author",
431
    taxon_match."*Name_matched_url",
432
    taxon_match."*Author_matched",
433
    taxon_match."*Author_score",
434
    taxon_match."*Family_matched",
435
    taxon_match."*Family_score",
436
    taxon_match."*Name_matched_accepted_family",
437
    taxon_match."*Genus_matched",
438
    taxon_match."*Genus_score",
439
    taxon_match."*Specific_epithet_matched",
440
    taxon_match."*Specific_epithet_score",
441
    taxon_match."*Infraspecific_rank",
442
    taxon_match."*Infraspecific_epithet_matched",
443
    taxon_match."*Infraspecific_epithet_score",
444
    taxon_match."*Infraspecific_rank_2",
445
    taxon_match."*Infraspecific_epithet_2_matched",
446
    taxon_match."*Infraspecific_epithet_2_score",
447
    taxon_match."*Annotations",
448
    taxon_match."*Unmatched_terms",
449
    taxon_match."*Taxonomic_status",
450
    taxon_match."*Accepted_name",
451
    taxon_match."*Accepted_name_author",
452
    taxon_match."*Accepted_name_rank",
453
    taxon_match."*Accepted_name_url",
454
    taxon_match."*Accepted_name_species",
455
    taxon_match."*Accepted_name_family",
456
    taxon_match."*Selected",
457
    taxon_match."*Source",
458
    taxon_match."*Warnings",
459
    taxon_match."*Accepted_name_lsid",
460 13878 aaronmk
    taxon_match.is_valid_match,
461
    taxon_match.scrubbed_unique_taxon_name
462
   FROM taxon_match
463 14111 aaronmk
  WHERE (taxon_match."*Selected" = 'true'::text);
464 13878 aaronmk
465
466
--
467
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
468
--
469
470
COMMENT ON VIEW taxon_best_match IS '
471
to modify:
472
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
473
SELECT __
474
$$);
475
';
476
477
478
--
479 10778 aaronmk
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
480
--
481
482
CREATE VIEW "MatchedTaxon" AS
483 14110 aaronmk
 SELECT taxon_best_match.batch,
484
    taxon_best_match.match_num,
485 14111 aaronmk
    taxon_best_match."*Name_number",
486
    taxon_best_match."*Name_submitted",
487
    taxon_best_match."*Overall_score",
488
    taxon_best_match."*Name_matched",
489
    taxon_best_match."*Name_matched_rank",
490
    taxon_best_match."*Name_score",
491
    taxon_best_match."*Name_matched_author",
492
    taxon_best_match."*Name_matched_url",
493
    taxon_best_match."*Author_matched",
494
    taxon_best_match."*Author_score",
495
    taxon_best_match."*Family_matched",
496
    taxon_best_match."*Family_score",
497
    taxon_best_match."*Name_matched_accepted_family",
498
    taxon_best_match."*Genus_matched",
499
    taxon_best_match."*Genus_score",
500
    taxon_best_match."*Specific_epithet_matched",
501
    taxon_best_match."*Specific_epithet_score",
502
    taxon_best_match."*Infraspecific_rank",
503
    taxon_best_match."*Infraspecific_epithet_matched",
504
    taxon_best_match."*Infraspecific_epithet_score",
505
    taxon_best_match."*Infraspecific_rank_2",
506
    taxon_best_match."*Infraspecific_epithet_2_matched",
507
    taxon_best_match."*Infraspecific_epithet_2_score",
508
    taxon_best_match."*Annotations",
509
    taxon_best_match."*Unmatched_terms",
510
    taxon_best_match."*Taxonomic_status",
511
    taxon_best_match."*Accepted_name",
512
    taxon_best_match."*Accepted_name_author",
513
    taxon_best_match."*Accepted_name_rank",
514
    taxon_best_match."*Accepted_name_url",
515
    taxon_best_match."*Accepted_name_species",
516
    taxon_best_match."*Accepted_name_family",
517
    taxon_best_match."*Selected",
518
    taxon_best_match."*Source",
519
    taxon_best_match."*Warnings",
520
    taxon_best_match."*Accepted_name_lsid",
521 14110 aaronmk
    taxon_best_match.is_valid_match,
522
    taxon_best_match.scrubbed_unique_taxon_name,
523 14111 aaronmk
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
524 13498 aaronmk
        CASE
525 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")
526
            WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
527
            ELSE taxon_best_match."*Accepted_name_species"
528 13498 aaronmk
        END AS accepted_morphospecies_binomial
529 14110 aaronmk
   FROM taxon_best_match;
530 10778 aaronmk
531
532
--
533 13498 aaronmk
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
534
--
535
536
COMMENT ON VIEW "MatchedTaxon" IS '
537 13501 aaronmk
to modify:
538 13845 aaronmk
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
539 13647 aaronmk
SELECT __
540 13501 aaronmk
$$);
541 13498 aaronmk
';
542
543
544
--
545 10778 aaronmk
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
546
--
547
548
CREATE VIEW "ValidMatchedTaxon" AS
549 14108 aaronmk
 SELECT "MatchedTaxon".batch,
550 14105 aaronmk
    "MatchedTaxon".match_num,
551 14111 aaronmk
    "MatchedTaxon"."*Name_number",
552
    "MatchedTaxon"."*Name_submitted",
553
    "MatchedTaxon"."*Overall_score",
554
    "MatchedTaxon"."*Name_matched",
555
    "MatchedTaxon"."*Name_matched_rank",
556
    "MatchedTaxon"."*Name_score",
557
    "MatchedTaxon"."*Name_matched_author",
558
    "MatchedTaxon"."*Name_matched_url",
559
    "MatchedTaxon"."*Author_matched",
560
    "MatchedTaxon"."*Author_score",
561
    "MatchedTaxon"."*Family_matched",
562
    "MatchedTaxon"."*Family_score",
563
    "MatchedTaxon"."*Name_matched_accepted_family",
564
    "MatchedTaxon"."*Genus_matched",
565
    "MatchedTaxon"."*Genus_score",
566
    "MatchedTaxon"."*Specific_epithet_matched",
567
    "MatchedTaxon"."*Specific_epithet_score",
568
    "MatchedTaxon"."*Infraspecific_rank",
569
    "MatchedTaxon"."*Infraspecific_epithet_matched",
570
    "MatchedTaxon"."*Infraspecific_epithet_score",
571
    "MatchedTaxon"."*Infraspecific_rank_2",
572
    "MatchedTaxon"."*Infraspecific_epithet_2_matched",
573
    "MatchedTaxon"."*Infraspecific_epithet_2_score",
574
    "MatchedTaxon"."*Annotations",
575
    "MatchedTaxon"."*Unmatched_terms",
576
    "MatchedTaxon"."*Taxonomic_status",
577
    "MatchedTaxon"."*Accepted_name",
578
    "MatchedTaxon"."*Accepted_name_author",
579
    "MatchedTaxon"."*Accepted_name_rank",
580
    "MatchedTaxon"."*Accepted_name_url",
581
    "MatchedTaxon"."*Accepted_name_species",
582
    "MatchedTaxon"."*Accepted_name_family",
583
    "MatchedTaxon"."*Selected",
584
    "MatchedTaxon"."*Source",
585
    "MatchedTaxon"."*Warnings",
586
    "MatchedTaxon"."*Accepted_name_lsid",
587 14108 aaronmk
    "MatchedTaxon".is_valid_match,
588 13800 aaronmk
    "MatchedTaxon".scrubbed_unique_taxon_name,
589 14103 aaronmk
    "MatchedTaxon"."taxonomicStatus",
590 13498 aaronmk
    "MatchedTaxon".accepted_morphospecies_binomial
591 11708 aaronmk
   FROM "MatchedTaxon"
592 14108 aaronmk
  WHERE "MatchedTaxon".is_valid_match;
593 10778 aaronmk
594
595
--
596
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
597
--
598
599 13443 aaronmk
COMMENT ON VIEW "ValidMatchedTaxon" IS '
600
to update, use * as the column list
601
';
602 10778 aaronmk
603
604
--
605
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
606
--
607
608
CREATE TABLE batch (
609
    id text NOT NULL,
610
    id_by_time text,
611
    time_submitted timestamp with time zone DEFAULT now(),
612
    client_version text
613
);
614
615
616
--
617
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
618
--
619
620
CREATE TABLE batch_download_settings (
621
    id text NOT NULL,
622
    "E-mail" text,
623
    "Id" text,
624
    "Job type" text,
625
    "Contains Id" boolean,
626
    "Start time" text,
627
    "Finish time" text,
628
    "TNRS version" text,
629
    "Sources selected" text,
630
    "Match threshold" double precision,
631
    "Classification" text,
632
    "Allow partial matches?" boolean,
633
    "Sort by source" boolean,
634
    "Constrain by higher taxonomy" boolean
635
);
636
637
638
--
639
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
640
--
641
642 13575 aaronmk
COMMENT ON TABLE batch_download_settings IS '
643
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
644
';
645 10778 aaronmk
646
647
--
648
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
649
--
650
651
CREATE TABLE client_version (
652
    id text NOT NULL,
653
    global_rev integer NOT NULL,
654
    "/lib/tnrs.py rev" integer,
655
    "/bin/tnrs_db rev" integer
656
);
657
658
659
--
660
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
661
--
662
663 13575 aaronmk
COMMENT ON TABLE client_version IS '
664
contains svn revisions
665
';
666 10778 aaronmk
667
668
--
669
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
670
--
671
672 13575 aaronmk
COMMENT ON COLUMN client_version.global_rev IS '
673
from `svn info .` > Last Changed Rev
674
';
675 10778 aaronmk
676
677
--
678
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
679
--
680
681 13575 aaronmk
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
682
from `svn info lib/tnrs.py` > Last Changed Rev
683
';
684 10778 aaronmk
685
686
--
687
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
688
--
689
690 13575 aaronmk
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
691
from `svn info bin/tnrs_db` > Last Changed Rev
692
';
693 10778 aaronmk
694
695
--
696 13866 aaronmk
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
697
--
698
699
CREATE VIEW taxon_match_input AS
700 14111 aaronmk
 SELECT taxon_match."*Name_number" AS "Name_number",
701
    taxon_match."*Name_submitted" AS "Name_submitted",
702
    taxon_match."*Overall_score" AS "Overall_score",
703
    taxon_match."*Name_matched" AS "Name_matched",
704
    taxon_match."*Name_matched_rank" AS "Name_matched_rank",
705
    taxon_match."*Name_score" AS "Name_score",
706
    taxon_match."*Name_matched_author" AS "Name_matched_author",
707
    taxon_match."*Name_matched_url" AS "Name_matched_url",
708
    taxon_match."*Author_matched" AS "Author_matched",
709
    taxon_match."*Author_score" AS "Author_score",
710
    taxon_match."*Family_matched" AS "Family_matched",
711
    taxon_match."*Family_score" AS "Family_score",
712
    taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
713
    taxon_match."*Genus_matched" AS "Genus_matched",
714
    taxon_match."*Genus_score" AS "Genus_score",
715
    taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
716
    taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
717
    taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
718
    taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
719
    taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
720
    taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
721
    taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
722
    taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
723
    taxon_match."*Annotations" AS "Annotations",
724
    taxon_match."*Unmatched_terms" AS "Unmatched_terms",
725
    taxon_match."*Taxonomic_status" AS "Taxonomic_status",
726
    taxon_match."*Accepted_name" AS "Accepted_name",
727
    taxon_match."*Accepted_name_author" AS "Accepted_name_author",
728
    taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
729
    taxon_match."*Accepted_name_url" AS "Accepted_name_url",
730
    taxon_match."*Accepted_name_species" AS "Accepted_name_species",
731
    taxon_match."*Accepted_name_family" AS "Accepted_name_family",
732
    taxon_match."*Selected" AS "Selected",
733
    taxon_match."*Source" AS "Source",
734
    taxon_match."*Warnings" AS "Warnings",
735
    taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
736 13866 aaronmk
   FROM taxon_match;
737
738
739
--
740
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
741
--
742
743
CREATE TABLE taxon_match_input__copy_to (
744
    "Name_number" integer,
745
    "Name_submitted" text,
746
    "Overall_score" double precision,
747
    "Name_matched" text,
748
    "Name_matched_rank" text,
749
    "Name_score" double precision,
750
    "Name_matched_author" text,
751
    "Name_matched_url" text,
752
    "Author_matched" text,
753
    "Author_score" double precision,
754
    "Family_matched" text,
755
    "Family_score" double precision,
756
    "Name_matched_accepted_family" text,
757
    "Genus_matched" text,
758
    "Genus_score" double precision,
759
    "Specific_epithet_matched" text,
760
    "Specific_epithet_score" double precision,
761
    "Infraspecific_rank" text,
762
    "Infraspecific_epithet_matched" text,
763
    "Infraspecific_epithet_score" double precision,
764
    "Infraspecific_rank_2" text,
765
    "Infraspecific_epithet_2_matched" text,
766
    "Infraspecific_epithet_2_score" double precision,
767
    "Annotations" text,
768
    "Unmatched_terms" text,
769
    "Taxonomic_status" text,
770
    "Accepted_name" text,
771
    "Accepted_name_author" text,
772
    "Accepted_name_rank" text,
773
    "Accepted_name_url" text,
774
    "Accepted_name_species" text,
775
    "Accepted_name_family" text,
776
    "Selected" text,
777
    "Source" text,
778
    "Warnings" text,
779
    "Accepted_name_lsid" text
780
);
781
782
783
--
784 11964 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
785
--
786
787
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
788 14111 aaronmk
 SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
789
    taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
790
    COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
791
    taxon_match."*Genus_matched" AS scrubbed_genus,
792
    taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
793
    taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
794
    taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
795
    taxon_match."*Name_matched_author" AS scrubbed_author,
796
    taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
797
    (taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
798 13861 aaronmk
   FROM taxon_match;
799 11964 aaronmk
800
801
--
802 11965 aaronmk
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
803
--
804
805 13575 aaronmk
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
806 13846 aaronmk
to modify:
807
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
808
SELECT __
809
$$);
810
811 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.
812
';
813 11965 aaronmk
814
815
--
816 11964 aaronmk
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
817
--
818
819
CREATE VIEW taxon_scrub AS
820 13800 aaronmk
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
821 14108 aaronmk
    "ValidMatchedTaxon".batch,
822 14105 aaronmk
    "ValidMatchedTaxon".match_num,
823 14111 aaronmk
    "ValidMatchedTaxon"."*Name_number",
824
    "ValidMatchedTaxon"."*Name_submitted",
825
    "ValidMatchedTaxon"."*Overall_score",
826
    "ValidMatchedTaxon"."*Name_matched",
827
    "ValidMatchedTaxon"."*Name_matched_rank",
828
    "ValidMatchedTaxon"."*Name_score",
829
    "ValidMatchedTaxon"."*Name_matched_author",
830
    "ValidMatchedTaxon"."*Name_matched_url",
831
    "ValidMatchedTaxon"."*Author_matched",
832
    "ValidMatchedTaxon"."*Author_score",
833
    "ValidMatchedTaxon"."*Family_matched",
834
    "ValidMatchedTaxon"."*Family_score",
835
    "ValidMatchedTaxon"."*Name_matched_accepted_family",
836
    "ValidMatchedTaxon"."*Genus_matched",
837
    "ValidMatchedTaxon"."*Genus_score",
838
    "ValidMatchedTaxon"."*Specific_epithet_matched",
839
    "ValidMatchedTaxon"."*Specific_epithet_score",
840
    "ValidMatchedTaxon"."*Infraspecific_rank",
841
    "ValidMatchedTaxon"."*Infraspecific_epithet_matched",
842
    "ValidMatchedTaxon"."*Infraspecific_epithet_score",
843
    "ValidMatchedTaxon"."*Infraspecific_rank_2",
844
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
845
    "ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
846
    "ValidMatchedTaxon"."*Annotations",
847
    "ValidMatchedTaxon"."*Unmatched_terms",
848
    "ValidMatchedTaxon"."*Taxonomic_status",
849
    "ValidMatchedTaxon"."*Accepted_name",
850
    "ValidMatchedTaxon"."*Accepted_name_author",
851
    "ValidMatchedTaxon"."*Accepted_name_rank",
852
    "ValidMatchedTaxon"."*Accepted_name_url",
853
    "ValidMatchedTaxon"."*Accepted_name_species",
854
    "ValidMatchedTaxon"."*Accepted_name_family",
855
    "ValidMatchedTaxon"."*Selected",
856
    "ValidMatchedTaxon"."*Source",
857
    "ValidMatchedTaxon"."*Warnings",
858
    "ValidMatchedTaxon"."*Accepted_name_lsid",
859 14108 aaronmk
    "ValidMatchedTaxon".is_valid_match,
860 14103 aaronmk
    "ValidMatchedTaxon"."taxonomicStatus",
861 13800 aaronmk
    "ValidMatchedTaxon".accepted_morphospecies_binomial,
862
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
863
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
864
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
865
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
866
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
867
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
868
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
869
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
870
    "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
871 13532 aaronmk
        CASE
872 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")
873
            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")
874 13532 aaronmk
            ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
875
        END AS scrubbed_morphospecies_binomial
876 11964 aaronmk
   FROM ("ValidMatchedTaxon"
877
   LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
878
879
880
--
881
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
882
--
883
884 13443 aaronmk
COMMENT ON VIEW taxon_scrub IS '
885 13531 aaronmk
to modify:
886 13845 aaronmk
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
887 13647 aaronmk
SELECT __
888 13531 aaronmk
$$);
889 13443 aaronmk
';
890 11964 aaronmk
891
892
--
893 10778 aaronmk
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
894
--
895
896
ALTER TABLE ONLY batch_download_settings
897
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
898
899
900
--
901
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
902
--
903
904
ALTER TABLE ONLY batch
905
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
906
907
908
--
909
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
910
--
911
912
ALTER TABLE ONLY batch
913
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
914
915
916
--
917
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
918
--
919
920
ALTER TABLE ONLY client_version
921
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
922
923
924
--
925 13868 aaronmk
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
926 10778 aaronmk
--
927
928 13861 aaronmk
ALTER TABLE ONLY taxon_match
929 13868 aaronmk
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
930 10778 aaronmk
931 14125 aaronmk
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
932 10778 aaronmk
933 14125 aaronmk
934 10778 aaronmk
--
935 10793 aaronmk
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
936
--
937
938
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
939
940
941
--
942 13879 aaronmk
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
943 13589 aaronmk
--
944
945 14111 aaronmk
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
946 13589 aaronmk
947
948
--
949 13879 aaronmk
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
950 13874 aaronmk
--
951
952 14111 aaronmk
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
953 13874 aaronmk
954
955
--
956 13879 aaronmk
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
957 11607 aaronmk
--
958
959 14111 aaronmk
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
960 11607 aaronmk
961
962
--
963 10778 aaronmk
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
964
--
965
966
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
967
968
969
--
970 13868 aaronmk
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
971 13866 aaronmk
--
972
973 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();
974 13866 aaronmk
975
976
--
977 13868 aaronmk
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
978 13567 aaronmk
--
979
980 13868 aaronmk
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
981 13567 aaronmk
982
983
--
984 14122 aaronmk
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
985
--
986
987
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
988
989
990
--
991 13868 aaronmk
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
992 13578 aaronmk
--
993
994 13868 aaronmk
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
995 13578 aaronmk
996
997
--
998 13868 aaronmk
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
999 10778 aaronmk
--
1000
1001 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();
1002 10778 aaronmk
1003
1004
--
1005
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1006
--
1007
1008
ALTER TABLE ONLY batch
1009
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
1010
1011
1012
--
1013
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1014
--
1015
1016
ALTER TABLE ONLY batch_download_settings
1017
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1018
1019
1020
--
1021 13868 aaronmk
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1022 10778 aaronmk
--
1023
1024 13861 aaronmk
ALTER TABLE ONLY taxon_match
1025 13868 aaronmk
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1026 10778 aaronmk
1027
1028
--
1029
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
1030
--
1031
1032
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
1033
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
1034
GRANT ALL ON SCHEMA "TNRS" TO bien;
1035
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
1036
1037
1038
--
1039 13861 aaronmk
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
1040 10778 aaronmk
--
1041
1042 13861 aaronmk
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
1043
REVOKE ALL ON TABLE taxon_match FROM bien;
1044
GRANT ALL ON TABLE taxon_match TO bien;
1045
GRANT SELECT ON TABLE taxon_match TO bien_read;
1046 10778 aaronmk
1047
1048
--
1049 13878 aaronmk
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
1050
--
1051
1052
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
1053
REVOKE ALL ON TABLE taxon_best_match FROM bien;
1054
GRANT ALL ON TABLE taxon_best_match TO bien;
1055
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
1056
1057
1058
--
1059 11912 aaronmk
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1060
--
1061
1062
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
1063
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
1064
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
1065
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
1066
1067
1068
--
1069
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
1070
--
1071
1072
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
1073
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
1074
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
1075
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
1076
1077
1078
--
1079 13866 aaronmk
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
1080
--
1081
1082
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
1083
REVOKE ALL ON TABLE taxon_match_input FROM bien;
1084
GRANT ALL ON TABLE taxon_match_input TO bien;
1085
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
1086
1087
1088
--
1089 11912 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
1090
--
1091
1092
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
1093
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
1094
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
1095
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
1096
1097
1098
--
1099
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
1100
--
1101
1102
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
1103
REVOKE ALL ON TABLE taxon_scrub FROM bien;
1104
GRANT ALL ON TABLE taxon_scrub TO bien;
1105
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
1106
1107
1108
--
1109 10778 aaronmk
-- PostgreSQL database dump complete
1110
--