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);
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
BEGIN
107
	new."Accepted_scientific_name" = NULLIF(concat_ws(' '
108
		, NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'),
109
			new."Accepted_name")
110
		, new."Accepted_name"
111
		, new."Accepted_name_author"
112
		), '');
113
	new."Is_homonym" = COALESCE(genus_is_homonym, family_is_homonym);
114
	/* exclude homonyms because these are not valid matches (i.e. TNRS provides
115
	a name, but the name is not meaningful because it is not unambiguous). */
116
	new.is_valid_match = COALESCE(CASE
117
		WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
118
			THEN true
119
		ELSE -- consider genus
120
			(CASE
121
			WHEN new."Genus_score" =  1	   -- exact match
122
				THEN
123
				(CASE
124
				WHEN NOT genus_is_homonym THEN true
125
				ELSE "Specific_epithet_is_plant"
126
				END)
127
			WHEN new."Genus_score" >= 0.85 -- fuzzy match
128
				THEN "Specific_epithet_is_plant"
129
			ELSE NULL -- ambiguous
130
			END)
131
		END, false);
132
	new.scrubbed_taxon_name_with_author = COALESCE(
133
		new."Accepted_scientific_name", matched_taxon_name_with_author);
134
	
135
	RETURN new;
136
END;
137
$$;
138

    
139

    
140
--
141
-- Name: FUNCTION tnrs_populate_fields(); Type: COMMENT; Schema: TNRS; Owner: -
142
--
143

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

    
150

    
151
SET default_tablespace = '';
152

    
153
SET default_with_oids = false;
154

    
155
--
156
-- Name: tnrs; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
157
--
158

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

    
203

    
204
--
205
-- Name: TABLE tnrs; Type: COMMENT; Schema: TNRS; Owner: -
206
--
207

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

    
211

    
212
--
213
-- Name: AcceptedTaxon; Type: VIEW; Schema: TNRS; Owner: -
214
--
215

    
216
CREATE VIEW "AcceptedTaxon" AS
217
    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;
218

    
219

    
220
--
221
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
222
--
223

    
224
CREATE VIEW "MatchedTaxon" AS
225
    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.is_valid_match AS taxon_scrub__is_valid_match FROM tnrs;
226

    
227

    
228
--
229
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
230
--
231

    
232
CREATE VIEW "ValidMatchedTaxon" AS
233
    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".taxon_scrub__is_valid_match FROM "MatchedTaxon" WHERE "MatchedTaxon".taxon_scrub__is_valid_match;
234

    
235

    
236
--
237
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
238
--
239

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

    
242

    
243
--
244
-- Name: ScrubbedTaxon; Type: VIEW; Schema: TNRS; Owner: -
245
--
246

    
247
CREATE VIEW "ScrubbedTaxon" AS
248
    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", "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");
249

    
250

    
251
--
252
-- Name: VIEW "ScrubbedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
253
--
254

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

    
257

    
258
--
259
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
260
--
261

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

    
269

    
270
--
271
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
272
--
273

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

    
291

    
292
--
293
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
294
--
295

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

    
298

    
299
--
300
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
301
--
302

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

    
310

    
311
--
312
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
313
--
314

    
315
COMMENT ON TABLE client_version IS 'contains svn revisions';
316

    
317

    
318
--
319
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
320
--
321

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

    
324

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

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

    
331

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

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

    
338

    
339
--
340
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
341
--
342

    
343
ALTER TABLE ONLY batch_download_settings
344
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
345

    
346

    
347
--
348
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
349
--
350

    
351
ALTER TABLE ONLY batch
352
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
353

    
354

    
355
--
356
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
357
--
358

    
359
ALTER TABLE ONLY batch
360
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
361

    
362

    
363
--
364
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
365
--
366

    
367
ALTER TABLE ONLY client_version
368
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
369

    
370

    
371
--
372
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
373
--
374

    
375
ALTER TABLE ONLY tnrs
376
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
377

    
378

    
379
--
380
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
381
--
382

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

    
386

    
387
--
388
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
389
--
390

    
391
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
392

    
393

    
394
--
395
-- Name: tnrs__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
396
--
397

    
398
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
399

    
400

    
401
--
402
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
403
--
404

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

    
407

    
408
--
409
-- Name: tnrs_populate_fields; Type: TRIGGER; Schema: TNRS; Owner: -
410
--
411

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

    
414

    
415
--
416
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
417
--
418

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

    
422

    
423
--
424
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
425
--
426

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

    
430

    
431
--
432
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
433
--
434

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

    
438

    
439
--
440
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
441
--
442

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

    
448

    
449
--
450
-- Name: tnrs; Type: ACL; Schema: TNRS; Owner: -
451
--
452

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

    
458

    
459
--
460
-- PostgreSQL database dump complete
461
--
462

    
(8-8/10)