Project

General

Profile

1 10778 aaronmk
--
2
-- PostgreSQL database dump
3
--
4 10737 aaronmk
5 10778 aaronmk
SET statement_timeout = 0;
6
SET client_encoding = 'UTF8';
7
SET standard_conforming_strings = on;
8
SET check_function_bodies = false;
9
SET client_min_messages = warning;
10
11 10737 aaronmk
--
12 10778 aaronmk
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
13
--
14 10737 aaronmk
15 10778 aaronmk
--CREATE SCHEMA "TNRS";
16 10725 aaronmk
17
18 11614 aaronmk
--
19
-- Name: SCHEMA "TNRS"; Type: COMMENT; Schema: -; Owner: -
20
--
21
22
COMMENT ON SCHEMA "TNRS" IS 'IMPORTANT: when changing this schema, you must also make the same changes on vegbiendev:
23 11617 aaronmk
on vegbiendev:
24
# back up existing TNRS schema (in case of an accidental incorrect change):
25 11614 aaronmk
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
26 11616 aaronmk
$ svn up
27
$ svn di
28
# make the changes shown in the diff
29
## to change column types:
30 11614 aaronmk
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
31
  (''col'', ''new_type'')
32 11616 aaronmk
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
33 11617 aaronmk
$ rm=1 inputs/.TNRS/schema.sql.run
34
# repeat until `svn di` shows no diff
35
# back up new TNRS schema:
36
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")';
37 11614 aaronmk
38
39 10778 aaronmk
SET search_path = "TNRS", pg_catalog;
40
41
--
42
-- Name: batch__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
43
--
44
45
CREATE FUNCTION batch__fill() RETURNS trigger
46
    LANGUAGE plpgsql
47
    AS $$
48 10728 aaronmk
BEGIN
49
	new.id_by_time = new.time_submitted;
50
	new.id = COALESCE(new.id, new.id_by_time);
51
	RETURN new;
52
END;
53 10778 aaronmk
$$;
54 10728 aaronmk
55
56
--
57 10778 aaronmk
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
58
--
59 10728 aaronmk
60 10778 aaronmk
CREATE FUNCTION family_is_homonym(family text) RETURNS boolean
61
    LANGUAGE sql STABLE STRICT
62
    AS $_$
63
SELECT EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
64
$_$;
65 10736 aaronmk
66 10778 aaronmk
67 10736 aaronmk
--
68 10778 aaronmk
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
69
--
70 10736 aaronmk
71 10778 aaronmk
CREATE FUNCTION genus_is_homonym(genus text) RETURNS boolean
72
    LANGUAGE sql STABLE STRICT
73
    AS $_$
74
SELECT EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet WHERE "taxonNameOrEpithet" = $1)
75
$_$;
76 7844 aaronmk
77 9985 aaronmk
78 10778 aaronmk
--
79
-- Name: tnrs_populate_fields(); Type: FUNCTION; Schema: TNRS; Owner: -
80
--
81
82
CREATE FUNCTION tnrs_populate_fields() RETURNS trigger
83
    LANGUAGE plpgsql
84
    AS $$
85 9763 aaronmk
DECLARE
86 11628 aaronmk
	"Specific_epithet_is_plant" boolean :=
87
		(CASE
88
		WHEN   new."Infraspecific_epithet_matched"	 IS NOT NULL
89
			OR new."Infraspecific_epithet_2_matched" IS NOT NULL
90
			OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
91
			THEN true
92
		ELSE NULL -- ambiguous
93
		END);
94
	never_homonym boolean = COALESCE(new."Author_score" >= 0.6, false);
95
		-- author disambiguates
96
	family_is_homonym boolean = NOT never_homonym
97
		AND "TNRS".family_is_homonym(new."Family_matched");
98
	genus_is_homonym  boolean = NOT never_homonym
99
		AND "TNRS".genus_is_homonym(new."Genus_matched");
100
	matched_taxon_name_with_author text = NULLIF(concat_ws(' '
101
		, NULLIF(NULLIF(new."Name_matched_accepted_family", 'Unknown'),
102
			new."Name_matched")
103
		, NULLIF(new."Name_matched", 'No suitable matches found.')
104
		, new."Name_matched_author"
105
		), '');
106 11643 aaronmk
	accepted_taxon_name_with_author text = NULLIF(concat_ws(' '
107 11628 aaronmk
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
108
			new."Accepted_name")
109
		, new."Accepted_name"
110
		, new."Accepted_name_author"
111
		), '');
112 11643 aaronmk
BEGIN
113 11629 aaronmk
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
114
	a name, but the name is not meaningful because it is not unambiguous). */
115
	new.is_valid_match = COALESCE(CASE
116 11628 aaronmk
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
117
			THEN true
118
		ELSE -- consider genus
119
			(CASE
120
			WHEN new."Genus_score" =  1	   -- exact match
121
				THEN
122
				(CASE
123
				WHEN NOT genus_is_homonym THEN true
124
				ELSE "Specific_epithet_is_plant"
125
				END)
126
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
127
				THEN "Specific_epithet_is_plant"
128
			ELSE NULL -- ambiguous
129
			END)
130 11629 aaronmk
		END, false);
131 11632 aaronmk
	new.scrubbed_unique_taxon_name = COALESCE(
132 11643 aaronmk
		accepted_taxon_name_with_author, matched_taxon_name_with_author);
133 11628 aaronmk
134
	RETURN new;
135 7134 aaronmk
END;
136 10778 aaronmk
$$;
137
138
139
--
140
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
141
--
142
143 10754 aaronmk
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
144
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
145 11615 aaronmk
runtime: 25 min ("5363526 rows affected, 1351907 ms execution time")
146 10754 aaronmk
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
147 11615 aaronmk
runtime: 1.5 min ("92633 ms")';
148 7134 aaronmk
149 7251 aaronmk
150 10778 aaronmk
SET default_tablespace = '';
151
152
SET default_with_oids = false;
153
154 10728 aaronmk
--
155 10778 aaronmk
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
156
--
157 7251 aaronmk
158 10778 aaronmk
CREATE TABLE tnrs (
159
    batch text DEFAULT now() NOT NULL,
160
    "Name_number" integer NOT NULL,
161
    "Name_submitted" text NOT NULL,
162
    "Overall_score" double precision,
163
    "Name_matched" text,
164
    "Name_matched_rank" text,
165
    "Name_score" double precision,
166
    "Name_matched_author" text,
167
    "Name_matched_url" text,
168
    "Author_matched" text,
169
    "Author_score" double precision,
170
    "Family_matched" text,
171
    "Family_score" double precision,
172
    "Name_matched_accepted_family" text,
173
    "Genus_matched" text,
174
    "Genus_score" double precision,
175
    "Specific_epithet_matched" text,
176
    "Specific_epithet_score" double precision,
177
    "Infraspecific_rank" text,
178
    "Infraspecific_epithet_matched" text,
179
    "Infraspecific_epithet_score" double precision,
180
    "Infraspecific_rank_2" text,
181
    "Infraspecific_epithet_2_matched" text,
182
    "Infraspecific_epithet_2_score" double precision,
183
    "Annotations" text,
184
    "Unmatched_terms" text,
185
    "Taxonomic_status" text,
186
    "Accepted_name" text,
187
    "Accepted_name_author" text,
188
    "Accepted_name_rank" text,
189
    "Accepted_name_url" text,
190
    "Accepted_name_species" text,
191
    "Accepted_name_family" text,
192
    "Selected" text,
193
    "Source" text,
194
    "Warnings" text,
195
    "Accepted_name_lsid" text,
196 11628 aaronmk
    is_valid_match boolean NOT NULL,
197 11632 aaronmk
    scrubbed_unique_taxon_name text
198 10778 aaronmk
);
199 7823 aaronmk
200 9759 aaronmk
201 10778 aaronmk
--
202
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
203
--
204 7823 aaronmk
205 10787 aaronmk
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
206 11614 aaronmk
$ inputs/.TNRS/data.sql.run refresh';
207 10778 aaronmk
208
209
--
210
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
211
--
212
213
CREATE VIEW "MatchedTaxon" AS
214 11642 aaronmk
    SELECT tnrs.batch AS "*Name_matched.batch", tnrs."Name_submitted" AS "concatenatedScientificName", tnrs."Name_matched" AS "matchedTaxonName", tnrs."Name_matched_rank" AS "matchedTaxonRank", tnrs."Name_score" AS "*Name_matched.Name_score", tnrs."Name_matched_author" AS "matchedScientificNameAuthorship", tnrs."Name_matched_url" AS "matchedScientificNameID", tnrs."Author_score" AS "*Name_matched.Author_score", tnrs."Family_score" AS "matchedFamilyConfidence_fraction", COALESCE(tnrs."Name_matched_accepted_family", tnrs."Accepted_name_family") AS "matchedFamily", tnrs."Genus_matched" AS "matchedGenus", tnrs."Genus_score" AS "matchedGenusConfidence_fraction", tnrs."Specific_epithet_matched" AS "matchedSpecificEpithet", tnrs."Specific_epithet_score" AS "matchedSpeciesConfidence_fraction", tnrs."Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet", tnrs."Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score", tnrs."Annotations" AS "identificationQualifier", tnrs."Unmatched_terms" AS "morphospeciesSuffix", tnrs."Taxonomic_status" AS "taxonomicStatus", tnrs."Accepted_name" AS "acceptedTaxonName", tnrs."Accepted_name_author" AS "acceptedScientificNameAuthorship", tnrs."Accepted_name_rank" AS "acceptedTaxonRank", tnrs."Accepted_name_url" AS "acceptedScientificNameID", tnrs."Accepted_name_species" AS "*Name_matched.Accepted_name_species", tnrs."Accepted_name_family" AS "acceptedFamily", tnrs."Selected" AS "*Name_matched.Selected", tnrs."Source" AS "*Name_matched.Source", tnrs."Warnings" AS "*Name_matched.Warnings", tnrs."Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid", tnrs.is_valid_match AS taxon_scrub__is_valid_match, tnrs.scrubbed_unique_taxon_name FROM tnrs;
215 10778 aaronmk
216
217
--
218
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
219
--
220
221
CREATE VIEW "ValidMatchedTaxon" AS
222 11642 aaronmk
    SELECT "MatchedTaxon"."*Name_matched.batch", "MatchedTaxon"."concatenatedScientificName", "MatchedTaxon"."matchedTaxonName", "MatchedTaxon"."matchedTaxonRank", "MatchedTaxon"."*Name_matched.Name_score", "MatchedTaxon"."matchedScientificNameAuthorship", "MatchedTaxon"."matchedScientificNameID", "MatchedTaxon"."*Name_matched.Author_score", "MatchedTaxon"."matchedFamilyConfidence_fraction", "MatchedTaxon"."matchedFamily", "MatchedTaxon"."matchedGenus", "MatchedTaxon"."matchedGenusConfidence_fraction", "MatchedTaxon"."matchedSpecificEpithet", "MatchedTaxon"."matchedSpeciesConfidence_fraction", "MatchedTaxon"."matchedInfraspecificEpithet", "MatchedTaxon"."*Name_matched.Infraspecific_epithet_score", "MatchedTaxon"."identificationQualifier", "MatchedTaxon"."morphospeciesSuffix", "MatchedTaxon"."taxonomicStatus", "MatchedTaxon"."acceptedTaxonName", "MatchedTaxon"."acceptedScientificNameAuthorship", "MatchedTaxon"."acceptedTaxonRank", "MatchedTaxon"."acceptedScientificNameID", "MatchedTaxon"."*Name_matched.Accepted_name_species", "MatchedTaxon"."acceptedFamily", "MatchedTaxon"."*Name_matched.Selected", "MatchedTaxon"."*Name_matched.Source", "MatchedTaxon"."*Name_matched.Warnings", "MatchedTaxon"."*Name_matched.Accepted_name_lsid", "MatchedTaxon".taxon_scrub__is_valid_match, "MatchedTaxon".scrubbed_unique_taxon_name FROM "MatchedTaxon" WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
223 10778 aaronmk
224
225
--
226
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
227
--
228
229
COMMENT ON VIEW "ValidMatchedTaxon" IS 'to update, use * as the column list';
230
231
232
--
233
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
234
--
235
236
CREATE TABLE batch (
237
    id text NOT NULL,
238
    id_by_time text,
239
    time_submitted timestamp with time zone DEFAULT now(),
240
    client_version text
241
);
242
243
244
--
245
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
246
--
247
248
CREATE TABLE batch_download_settings (
249
    id text NOT NULL,
250
    "E-mail" text,
251
    "Id" text,
252
    "Job type" text,
253
    "Contains Id" boolean,
254
    "Start time" text,
255
    "Finish time" text,
256
    "TNRS version" text,
257
    "Sources selected" text,
258
    "Match threshold" double precision,
259
    "Classification" text,
260
    "Allow partial matches?" boolean,
261
    "Sort by source" boolean,
262
    "Constrain by higher taxonomy" boolean
263
);
264
265
266
--
267
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
268
--
269
270
COMMENT ON TABLE batch_download_settings IS 'stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt';
271
272
273
--
274
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
275
--
276
277
CREATE TABLE client_version (
278
    id text NOT NULL,
279
    global_rev integer NOT NULL,
280
    "/lib/tnrs.py rev" integer,
281
    "/bin/tnrs_db rev" integer
282
);
283
284
285
--
286
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
287
--
288
289
COMMENT ON TABLE client_version IS 'contains svn revisions';
290
291
292
--
293
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
294
--
295
296
COMMENT ON COLUMN client_version.global_rev IS 'from `svn info .` > Last Changed Rev';
297
298
299
--
300
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
301
--
302
303
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS 'from `svn info lib/tnrs.py` > Last Changed Rev';
304
305
306
--
307
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
308
--
309
310
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS 'from `svn info bin/tnrs_db` > Last Changed Rev';
311
312
313
--
314 11634 aaronmk
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
315
--
316
317
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
318
    SELECT tnrs."Name_submitted" AS scrubbed_unique_taxon_name, tnrs."Name_matched_rank" AS scrubbed_taxon_rank, tnrs."Name_matched_accepted_family" AS scrubbed_family, tnrs."Genus_matched" AS scrubbed_genus, tnrs."Specific_epithet_matched" AS scrubbed_specific_epithet, tnrs."Infraspecific_rank" AS scrubbed_infraspecific_rank, tnrs."Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet, tnrs."Name_matched_author" AS scrubbed_author, tnrs."Name_matched" AS scrubbed_taxon_name_no_author FROM tnrs;
319
320
321
--
322
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
323
--
324
325
CREATE VIEW taxon_scrub AS
326 11642 aaronmk
    SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name, "ValidMatchedTaxon"."*Name_matched.batch", "ValidMatchedTaxon"."concatenatedScientificName", "ValidMatchedTaxon"."matchedTaxonName", "ValidMatchedTaxon"."matchedTaxonRank", "ValidMatchedTaxon"."*Name_matched.Name_score", "ValidMatchedTaxon"."matchedScientificNameAuthorship", "ValidMatchedTaxon"."matchedScientificNameID", "ValidMatchedTaxon"."*Name_matched.Author_score", "ValidMatchedTaxon"."matchedFamilyConfidence_fraction", "ValidMatchedTaxon"."matchedFamily", "ValidMatchedTaxon"."matchedGenus", "ValidMatchedTaxon"."matchedGenusConfidence_fraction", "ValidMatchedTaxon"."matchedSpecificEpithet", "ValidMatchedTaxon"."matchedSpeciesConfidence_fraction", "ValidMatchedTaxon"."matchedInfraspecificEpithet", "ValidMatchedTaxon"."*Name_matched.Infraspecific_epithet_score", "ValidMatchedTaxon"."identificationQualifier", "ValidMatchedTaxon"."morphospeciesSuffix", "ValidMatchedTaxon"."taxonomicStatus", "ValidMatchedTaxon"."acceptedTaxonName", "ValidMatchedTaxon"."acceptedScientificNameAuthorship", "ValidMatchedTaxon"."acceptedTaxonRank", "ValidMatchedTaxon"."acceptedScientificNameID", "ValidMatchedTaxon"."*Name_matched.Accepted_name_species", "ValidMatchedTaxon"."acceptedFamily", "ValidMatchedTaxon"."*Name_matched.Selected", "ValidMatchedTaxon"."*Name_matched.Source", "ValidMatchedTaxon"."*Name_matched.Warnings", "ValidMatchedTaxon"."*Name_matched.Accepted_name_lsid", "ValidMatchedTaxon".taxon_scrub__is_valid_match, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author, "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author FROM ("ValidMatchedTaxon" NATURAL LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*");
327 11634 aaronmk
328
329
--
330
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
331
--
332
333
COMMENT ON VIEW taxon_scrub IS 'to update, use * as the column list';
334
335
336
--
337 10778 aaronmk
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
338
--
339
340
ALTER TABLE ONLY batch_download_settings
341
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
342
343
344
--
345
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
346
--
347
348
ALTER TABLE ONLY batch
349
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
350
351
352
--
353
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
354
--
355
356
ALTER TABLE ONLY batch
357
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
358
359
360
--
361
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
362
--
363
364
ALTER TABLE ONLY client_version
365
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
366
367
368
--
369
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
370
--
371
372
ALTER TABLE ONLY tnrs
373
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
374
375
376
--
377
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
378
--
379
380
ALTER TABLE ONLY tnrs
381
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
382
383
384
--
385 10793 aaronmk
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
386
--
387
388
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
389
390
391
--
392 11607 aaronmk
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
393
--
394
395
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
396
397
398
--
399 10778 aaronmk
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
400
--
401
402
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
403
404
405
--
406
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
407
--
408
409
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
410
411
412
--
413
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
414
--
415
416
ALTER TABLE ONLY batch
417
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
418
419
420
--
421
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
422
--
423
424
ALTER TABLE ONLY batch_download_settings
425
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
426
427
428
--
429
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
430
--
431
432
ALTER TABLE ONLY tnrs
433
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
434
435
436
--
437
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
438
--
439
440
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
441
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
442
GRANT ALL ON SCHEMA "TNRS" TO bien;
443
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
444
445
446
--
447
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
448
--
449
450
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
451
REVOKE ALL ON TABLE tnrs FROM bien;
452
GRANT ALL ON TABLE tnrs TO bien;
453
GRANT SELECT ON TABLE tnrs TO bien_read;
454
455
456
--
457
-- PostgreSQL database dump complete
458
--