Project

General

Profile

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

    
5
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
--
12
-- Name: TNRS; Type: SCHEMA; Schema: -; Owner: -
13
--
14

    
15
--CREATE SCHEMA "TNRS";
16

    
17

    
18
--
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
on vegbiendev:
24
# back up existing TNRS schema (in case of an accidental incorrect change):
25
$ make backups/TNRS.backup-remake # runtime: 3 min ("real 2m44.277s")
26
$ svn up
27
$ svn di
28
# make the changes shown in the diff
29
## to change column types:
30
SELECT util.set_col_types(''"TNRS".tnrs'', ARRAY[
31
  (''col'', ''new_type'')
32
]::util.col_cast[]); -- runtime: 9 min ("531282 ms")
33
$ 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

    
38

    
39
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
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
$$;
54

    
55

    
56
--
57
-- Name: family_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
58
--
59

    
60
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

    
66

    
67
--
68
-- Name: genus_is_homonym(text); Type: FUNCTION; Schema: TNRS; Owner: -
69
--
70

    
71
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

    
77

    
78
--
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
DECLARE
86
    "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); -- author disambiguates
95
    family_is_homonym boolean = NOT never_homonym AND "TNRS".family_is_homonym(new."Family_matched");
96
    genus_is_homonym  boolean = NOT never_homonym AND "TNRS".genus_is_homonym( new."Genus_matched" );
97
BEGIN
98
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
99
        , NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
100
        , new."Accepted_name"
101
        , new."Accepted_name_author"
102
    ), '');
103
    new."Max_score" = GREATEST(
104
          new."Overall_score"
105
        , new."Family_score"
106
        , new."Genus_score"
107
        , new."Specific_epithet_score"
108
    );
109
    new."Is_homonym" = COALESCE(genus_is_homonym, family_is_homonym);
110
    new."Is_plant" = (CASE
111
        WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
112
            THEN true
113
        ELSE -- consider genus
114
            (CASE
115
            WHEN new."Genus_score" =  1    -- exact match
116
                THEN
117
                (CASE
118
                WHEN NOT genus_is_homonym THEN true
119
                ELSE "Specific_epithet_is_plant"
120
                END)
121
            WHEN new."Genus_score" >= 0.85 -- fuzzy match
122
                THEN "Specific_epithet_is_plant"
123
            ELSE NULL -- ambiguous
124
            END)
125
        END);
126
    /* exclude homonyms because these are not valid matches (i.e. TNRS provides
127
    a name, but the name is not meaningful because it is not unambiguous).
128
    don't need to consider Max_score because Is_plant will always be false when
129
    the Max_score is insufficient (<0.8). */
130
    new.is_valid_match = COALESCE(new."Is_plant", false);
131
    
132
    RETURN new;
133
END;
134
$$;
135

    
136

    
137
--
138
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
139
--
140

    
141
COMMENT ON FUNCTION tnrs_populate_fields() IS 'IMPORTANT: when changing this function, you must regenerate the derived cols:
142
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
143
runtime: 25 min ("5363526 rows affected, 1351907 ms execution time")
144
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
145
runtime: 1.5 min ("92633 ms")';
146

    
147

    
148
SET default_tablespace = '';
149

    
150
SET default_with_oids = false;
151

    
152
--
153
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
154
--
155

    
156
CREATE TABLE tnrs (
157
    batch text DEFAULT now() NOT NULL,
158
    "Name_number" integer NOT NULL,
159
    "Name_submitted" text NOT NULL,
160
    "Overall_score" double precision,
161
    "Name_matched" text,
162
    "Name_matched_rank" text,
163
    "Name_score" double precision,
164
    "Name_matched_author" text,
165
    "Name_matched_url" text,
166
    "Author_matched" text,
167
    "Author_score" double precision,
168
    "Family_matched" text,
169
    "Family_score" double precision,
170
    "Name_matched_accepted_family" text,
171
    "Genus_matched" text,
172
    "Genus_score" double precision,
173
    "Specific_epithet_matched" text,
174
    "Specific_epithet_score" double precision,
175
    "Infraspecific_rank" text,
176
    "Infraspecific_epithet_matched" text,
177
    "Infraspecific_epithet_score" double precision,
178
    "Infraspecific_rank_2" text,
179
    "Infraspecific_epithet_2_matched" text,
180
    "Infraspecific_epithet_2_score" double precision,
181
    "Annotations" text,
182
    "Unmatched_terms" text,
183
    "Taxonomic_status" text,
184
    "Accepted_name" text,
185
    "Accepted_name_author" text,
186
    "Accepted_name_rank" text,
187
    "Accepted_name_url" text,
188
    "Accepted_name_species" text,
189
    "Accepted_name_family" text,
190
    "Selected" text,
191
    "Source" text,
192
    "Warnings" text,
193
    "Accepted_name_lsid" text,
194
    "Accepted_scientific_name" text,
195
    "Max_score" double precision,
196
    "Is_homonym" boolean,
197
    "Is_plant" boolean,
198
    is_valid_match boolean NOT NULL
199
);
200

    
201

    
202
--
203
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
204
--
205

    
206
COMMENT ON TABLE tnrs IS 'IMPORTANT: when changing this table''s schema, you may need to re-run TNRS:
207
$ inputs/.TNRS/data.sql.run refresh';
208

    
209

    
210
--
211
-- Name: AcceptedTaxon; Type: VIEW; Schema: TNRS; Owner: -
212
--
213

    
214
CREATE VIEW "AcceptedTaxon" AS
215
    SELECT tnrs.batch AS "*Accepted_name.batch", tnrs."Name_submitted" AS "acceptedScientificName", tnrs."Genus_matched" AS "acceptedGenus", tnrs."Specific_epithet_matched" AS "acceptedSpecificEpithet", tnrs."Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet", tnrs."Taxonomic_status" AS "acceptedTaxonomicStatus", tnrs."Selected" AS "*Accepted_name.Selected", tnrs."Source" AS "*Accepted_name.Source", tnrs."Warnings" AS "*Accepted_name.Warnings", tnrs."Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid" FROM tnrs;
216

    
217

    
218
--
219
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
220
--
221

    
222
CREATE VIEW "MatchedTaxon" AS
223
    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."Accepted_scientific_name" AS "acceptedScientificName", tnrs."Max_score" AS "matchedTaxonConfidence_fraction", tnrs.is_valid_match AS taxon_scrub__is_valid_match FROM tnrs;
224

    
225

    
226
--
227
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
228
--
229

    
230
CREATE VIEW "ValidMatchedTaxon" AS
231
    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"."acceptedScientificName", "MatchedTaxon"."matchedTaxonConfidence_fraction", "MatchedTaxon".taxon_scrub__is_valid_match FROM "MatchedTaxon" WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
232

    
233

    
234
--
235
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
236
--
237

    
238
COMMENT ON VIEW "ValidMatchedTaxon" IS 'to update, use * as the column list';
239

    
240

    
241
--
242
-- Name: ScrubbedTaxon; Type: VIEW; Schema: TNRS; Owner: -
243
--
244

    
245
CREATE VIEW "ScrubbedTaxon" AS
246
    SELECT "ValidMatchedTaxon"."acceptedScientificName", "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"."matchedTaxonConfidence_fraction", "AcceptedTaxon"."*Accepted_name.batch", "AcceptedTaxon"."acceptedGenus", "AcceptedTaxon"."acceptedSpecificEpithet", "AcceptedTaxon"."acceptedInfraspecificEpithet", "AcceptedTaxon"."acceptedTaxonomicStatus", "AcceptedTaxon"."*Accepted_name.Selected", "AcceptedTaxon"."*Accepted_name.Source", "AcceptedTaxon"."*Accepted_name.Warnings", "AcceptedTaxon"."*Accepted_name.Accepted_name_lsid" FROM ("ValidMatchedTaxon" NATURAL LEFT JOIN "AcceptedTaxon");
247

    
248

    
249
--
250
-- Name: VIEW "ScrubbedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
251
--
252

    
253
COMMENT ON VIEW "ScrubbedTaxon" IS 'to update, use * as the column list';
254

    
255

    
256
--
257
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
258
--
259

    
260
CREATE TABLE batch (
261
    id text NOT NULL,
262
    id_by_time text,
263
    time_submitted timestamp with time zone DEFAULT now(),
264
    client_version text
265
);
266

    
267

    
268
--
269
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
270
--
271

    
272
CREATE TABLE batch_download_settings (
273
    id text NOT NULL,
274
    "E-mail" text,
275
    "Id" text,
276
    "Job type" text,
277
    "Contains Id" boolean,
278
    "Start time" text,
279
    "Finish time" text,
280
    "TNRS version" text,
281
    "Sources selected" text,
282
    "Match threshold" double precision,
283
    "Classification" text,
284
    "Allow partial matches?" boolean,
285
    "Sort by source" boolean,
286
    "Constrain by higher taxonomy" boolean
287
);
288

    
289

    
290
--
291
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
292
--
293

    
294
COMMENT ON TABLE batch_download_settings IS 'stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt';
295

    
296

    
297
--
298
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
299
--
300

    
301
CREATE TABLE client_version (
302
    id text NOT NULL,
303
    global_rev integer NOT NULL,
304
    "/lib/tnrs.py rev" integer,
305
    "/bin/tnrs_db rev" integer
306
);
307

    
308

    
309
--
310
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
311
--
312

    
313
COMMENT ON TABLE client_version IS 'contains svn revisions';
314

    
315

    
316
--
317
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
318
--
319

    
320
COMMENT ON COLUMN client_version.global_rev IS 'from `svn info .` > Last Changed Rev';
321

    
322

    
323
--
324
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
325
--
326

    
327
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS 'from `svn info lib/tnrs.py` > Last Changed Rev';
328

    
329

    
330
--
331
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
332
--
333

    
334
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS 'from `svn info bin/tnrs_db` > Last Changed Rev';
335

    
336

    
337
--
338
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
339
--
340

    
341
ALTER TABLE ONLY batch_download_settings
342
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
343

    
344

    
345
--
346
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
347
--
348

    
349
ALTER TABLE ONLY batch
350
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
351

    
352

    
353
--
354
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
355
--
356

    
357
ALTER TABLE ONLY batch
358
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
359

    
360

    
361
--
362
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
363
--
364

    
365
ALTER TABLE ONLY client_version
366
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
367

    
368

    
369
--
370
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
371
--
372

    
373
ALTER TABLE ONLY tnrs
374
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
375

    
376

    
377
--
378
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
379
--
380

    
381
ALTER TABLE ONLY tnrs
382
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
383

    
384

    
385
--
386
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
387
--
388

    
389
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
390

    
391

    
392
--
393
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
394
--
395

    
396
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
397

    
398

    
399
--
400
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
401
--
402

    
403
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
404

    
405

    
406
--
407
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
408
--
409

    
410
CREATE TRIGGER tnrs_populate_fields BEFORE INSERT OR UPDATE ON tnrs FOR EACH ROW EXECUTE PROCEDURE tnrs_populate_fields();
411

    
412

    
413
--
414
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
415
--
416

    
417
ALTER TABLE ONLY batch
418
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
419

    
420

    
421
--
422
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
423
--
424

    
425
ALTER TABLE ONLY batch_download_settings
426
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
427

    
428

    
429
--
430
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
431
--
432

    
433
ALTER TABLE ONLY tnrs
434
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
435

    
436

    
437
--
438
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
439
--
440

    
441
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
442
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
443
GRANT ALL ON SCHEMA "TNRS" TO bien;
444
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
445

    
446

    
447
--
448
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
449
--
450

    
451
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
452
REVOKE ALL ON TABLE tnrs FROM bien;
453
GRANT ALL ON TABLE tnrs TO bien;
454
GRANT SELECT ON TABLE tnrs TO bien_read;
455

    
456

    
457
--
458
-- PostgreSQL database dump complete
459
--
460

    
(8-8/10)