Project

General

Profile

1
--
2
-- PostgreSQL database dump
3
--
4

    
5
SET statement_timeout = 0;
6
SET lock_timeout = 0;
7
SET client_encoding = 'UTF8';
8
SET standard_conforming_strings = on;
9
SET check_function_bodies = false;
10
SET client_min_messages = warning;
11

    
12
--
13
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
14
--
15

    
16
--CREATE SCHEMA "TNRS";
17

    
18

    
19
--
20
-- Name: SCHEMA "TNRS"; Type: COMMENT; Schema: -; Owner: -
21
--
22

    
23
COMMENT ON SCHEMA "TNRS" IS '
24
IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
25
on vegbiendev:
26
# back up existing TNRS schema (in case of an accidental incorrect change):
27
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
28
$ svn up
29
$ svn di
30
# make the changes shown in the diff
31
## to change column types:
32
SELECT util.set_col_types(''"TNRS".taxon_match'', ARRAY[
33
  (''col'', ''new_type'')
34
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
35
$ rm=1 inputs/.TNRS/schema.sql.run
36
# repeat until `svn di` shows no diff
37
# back up new TNRS schema:
38
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
39
';
40

    
41

    
42
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
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
$$;
57

    
58

    
59
--
60
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
61
--
62

    
63
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

    
69

    
70
--
71
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
72
--
73

    
74
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

    
80

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

    
85
CREATE FUNCTION map_taxonomic_status(taxonomic_status_verbatim text, accepted_taxon_name_no_author text) RETURNS text
86
    LANGUAGE sql IMMUTABLE
87
    AS $_$
88
/* 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
SELECT CASE WHEN $2 IS NOT NULL THEN 'accepted' ELSE lower($1) END
92
$_$;
93

    
94

    
95
--
96
-- Name: taxon_match__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
97
--
98

    
99
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
100
    LANGUAGE plpgsql
101
    AS $$
102
BEGIN
103
	PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
104
	RETURN NULL;
105
END;
106
$$;
107

    
108

    
109
--
110
-- Name: taxon_match__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
111
--
112

    
113
CREATE FUNCTION taxon_match__fill() RETURNS trigger
114
    LANGUAGE plpgsql
115
    AS $$
116
BEGIN
117
	DECLARE
118
		"Specific_epithet_is_plant" boolean :=
119
			(CASE
120
			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
				THEN true
124
			ELSE NULL -- ambiguous
125
			END);
126
		never_homonym boolean = COALESCE(new."*Author_score" >= 0.6, false);
127
			-- author disambiguates
128
		family_is_homonym boolean = NOT never_homonym
129
			AND "TNRS".family_is_homonym(new."*Family_matched");
130
		genus_is_homonym  boolean = NOT never_homonym
131
			AND "TNRS".genus_is_homonym(new."*Genus_matched");
132
	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
		new.is_valid_match = new."*Taxonomic_status" != 'Invalid'
136
			AND COALESCE(CASE
137
			WHEN new."*Family_score" = 1 AND NOT family_is_homonym -- exact match
138
				THEN true
139
			ELSE -- consider genus
140
				(CASE
141
				WHEN new."*Genus_score" =  1	   -- exact match
142
					THEN
143
					(CASE
144
					WHEN NOT genus_is_homonym THEN true
145
					ELSE "Specific_epithet_is_plant"
146
					END)
147
				WHEN new."*Genus_score" >= 0.85 -- fuzzy match
148
					THEN "Specific_epithet_is_plant"
149
				ELSE NULL -- ambiguous
150
				END)
151
			END, false);
152
	END;
153
	
154
	DECLARE
155
		matched_taxon_name_with_author text = NULLIF(concat_ws(' '
156
			, NULLIF(NULLIF(new."*Name_matched_accepted_family", 'Unknown'),
157
				new."*Name_matched")
158
			, NULLIF(new."*Name_matched", 'No suitable matches found.')
159
			, new."*Name_matched_author"
160
			), '');
161
		accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
162
			, NULLIF(NULLIF(new."*Accepted_name_family", 'Unknown'),
163
				new."*Accepted_name")
164
			, new."*Accepted_name"
165
			, new."*Accepted_name_author"
166
			), '');
167
	BEGIN
168
		new.scrubbed_unique_taxon_name = COALESCE(
169
			accepted_taxon_name_with_author, matched_taxon_name_with_author);
170
	END;
171
	
172
	RETURN new;
173
END;
174
$$;
175

    
176

    
177
--
178
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
179
--
180

    
181
COMMENT ON FUNCTION taxon_match__fill() IS '
182
IMPORTANT: when changing this function, you must regenerate the derived cols:
183
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
184
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
185
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
186
runtime: 1.5 min ("92633 ms")
187
';
188

    
189

    
190
--
191
-- 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", ' '::text)
200
		FROM (SELECT new.*) new);
201
	
202
	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
	RETURN new;
211
END;
212
$$;
213

    
214

    
215
--
216
-- 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
-- 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
		new.match_num = "TNRS".taxon_match__match_num__next();
237
	END IF;
238
	RETURN new;
239
END;
240
$$;
241

    
242

    
243
--
244
-- 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
-- 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
-- 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
]::text[]
288
$$;
289

    
290

    
291
SET default_tablespace = '';
292

    
293
SET default_with_oids = false;
294

    
295
--
296
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
297
--
298

    
299
CREATE TABLE taxon_match (
300
    batch text DEFAULT now() NOT NULL,
301
    match_num integer NOT NULL,
302
    "*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
    is_valid_match boolean NOT NULL,
339
    scrubbed_unique_taxon_name text,
340
    "__accepted_{genus,specific_epithet}" text[],
341
    "[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
    CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text))))
346
);
347

    
348

    
349
--
350
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
351
--
352

    
353
COMMENT ON TABLE taxon_match IS '
354
whenever columns are renamed:
355
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
356

    
357
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

    
366
to populate a new column:
367
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
368
UPDATE "TNRS".taxon_match SET "col" = value;
369
	-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
370
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
371
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
372
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
373

    
374
to add a constraint: runtime: 3 min ("173620 ms")
375
';
376

    
377

    
378
--
379
-- 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
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
388
';
389

    
390

    
391
--
392
-- 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
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
401
';
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
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
414
';
415

    
416

    
417
--
418
-- 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
    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
    taxon_match.is_valid_match,
461
    taxon_match.scrubbed_unique_taxon_name
462
   FROM taxon_match
463
  WHERE (taxon_match."*Selected" = 'true'::text);
464

    
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
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
480
--
481

    
482
CREATE VIEW "MatchedTaxon" AS
483
 SELECT taxon_best_match.batch,
484
    taxon_best_match.match_num,
485
    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
    taxon_best_match.is_valid_match,
522
    taxon_best_match.scrubbed_unique_taxon_name,
523
    map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
524
        CASE
525
            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
        END AS accepted_morphospecies_binomial
529
   FROM taxon_best_match;
530

    
531

    
532
--
533
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
534
--
535

    
536
COMMENT ON VIEW "MatchedTaxon" IS '
537
to modify:
538
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
539
SELECT __
540
$$);
541
';
542

    
543

    
544
--
545
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
546
--
547

    
548
CREATE VIEW "ValidMatchedTaxon" AS
549
 SELECT "MatchedTaxon".batch,
550
    "MatchedTaxon".match_num,
551
    "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
    "MatchedTaxon".is_valid_match,
588
    "MatchedTaxon".scrubbed_unique_taxon_name,
589
    "MatchedTaxon"."taxonomicStatus",
590
    "MatchedTaxon".accepted_morphospecies_binomial
591
   FROM "MatchedTaxon"
592
  WHERE "MatchedTaxon".is_valid_match;
593

    
594

    
595
--
596
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
597
--
598

    
599
COMMENT ON VIEW "ValidMatchedTaxon" IS '
600
to update, use * as the column list
601
';
602

    
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
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

    
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
COMMENT ON TABLE client_version IS '
664
contains svn revisions
665
';
666

    
667

    
668
--
669
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
670
--
671

    
672
COMMENT ON COLUMN client_version.global_rev IS '
673
from `svn info .` > Last Changed Rev
674
';
675

    
676

    
677
--
678
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
679
--
680

    
681
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
682
from `svn info lib/tnrs.py` > Last Changed Rev
683
';
684

    
685

    
686
--
687
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
688
--
689

    
690
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
691
from `svn info bin/tnrs_db` > Last Changed Rev
692
';
693

    
694

    
695
--
696
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
697
--
698

    
699
CREATE VIEW taxon_match_input AS
700
 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
   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
-- 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
 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
   FROM taxon_match;
799

    
800

    
801
--
802
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
803
--
804

    
805
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
806
to modify:
807
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
808
SELECT __
809
$$);
810

    
811
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

    
814

    
815
--
816
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
817
--
818

    
819
CREATE VIEW taxon_scrub AS
820
 SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
821
    "ValidMatchedTaxon".batch,
822
    "ValidMatchedTaxon".match_num,
823
    "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
    "ValidMatchedTaxon".is_valid_match,
860
    "ValidMatchedTaxon"."taxonomicStatus",
861
    "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
        CASE
872
            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
            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
   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
COMMENT ON VIEW taxon_scrub IS '
885
to modify:
886
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
887
SELECT __
888
$$);
889
';
890

    
891

    
892
--
893
-- 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
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
926
--
927

    
928
ALTER TABLE ONLY taxon_match
929
    ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
930

    
931
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
932

    
933

    
934
--
935
-- 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
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
943
--
944

    
945
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
946

    
947

    
948
--
949
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
950
--
951

    
952
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
953

    
954

    
955
--
956
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
957
--
958

    
959
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
960

    
961

    
962
--
963
-- 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
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
971
--
972

    
973
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
974

    
975

    
976
--
977
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
978
--
979

    
980
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
981

    
982

    
983
--
984
-- 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
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
992
--
993

    
994
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
995

    
996

    
997
--
998
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
999
--
1000

    
1001
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

    
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
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
1022
--
1023

    
1024
ALTER TABLE ONLY taxon_match
1025
    ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
1026

    
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
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
1040
--
1041

    
1042
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

    
1047

    
1048
--
1049
-- 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
-- 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
-- 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
-- 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
-- PostgreSQL database dump complete
1110
--
1111

    
(7-7/9)