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
	/* 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
		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
		END, false);
131
	new.scrubbed_unique_taxon_name = COALESCE(
132
		new."Accepted_scientific_name", matched_taxon_name_with_author);
133
	
134
	RETURN new;
135
END;
136
$$;
137

    
138

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

    
143
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
runtime: 25 min ("5363526 rows affected, 1351907 ms execution time")
146
VACUUM ANALYZE "TNRS".tnrs -- to remove previous rows
147
runtime: 1.5 min ("92633 ms")';
148

    
149

    
150
SET default_tablespace = '';
151

    
152
SET default_with_oids = false;
153

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

    
158
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
    "Accepted_scientific_name" text,
197
    is_valid_match boolean NOT NULL,
198
    scrubbed_unique_taxon_name text
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.is_valid_match AS taxon_scrub__is_valid_match, tnrs.scrubbed_unique_taxon_name 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".taxon_scrub__is_valid_match, "MatchedTaxon".scrubbed_unique_taxon_name 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".taxon_scrub__is_valid_match, "ValidMatchedTaxon".scrubbed_unique_taxon_name, "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: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
251
--
252

    
253
CREATE TABLE batch (
254
    id text NOT NULL,
255
    id_by_time text,
256
    time_submitted timestamp with time zone DEFAULT now(),
257
    client_version text
258
);
259

    
260

    
261
--
262
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
263
--
264

    
265
CREATE TABLE batch_download_settings (
266
    id text NOT NULL,
267
    "E-mail" text,
268
    "Id" text,
269
    "Job type" text,
270
    "Contains Id" boolean,
271
    "Start time" text,
272
    "Finish time" text,
273
    "TNRS version" text,
274
    "Sources selected" text,
275
    "Match threshold" double precision,
276
    "Classification" text,
277
    "Allow partial matches?" boolean,
278
    "Sort by source" boolean,
279
    "Constrain by higher taxonomy" boolean
280
);
281

    
282

    
283
--
284
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
285
--
286

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

    
289

    
290
--
291
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace: 
292
--
293

    
294
CREATE TABLE client_version (
295
    id text NOT NULL,
296
    global_rev integer NOT NULL,
297
    "/lib/tnrs.py rev" integer,
298
    "/bin/tnrs_db rev" integer
299
);
300

    
301

    
302
--
303
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
304
--
305

    
306
COMMENT ON TABLE client_version IS 'contains svn revisions';
307

    
308

    
309
--
310
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
311
--
312

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

    
315

    
316
--
317
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
318
--
319

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

    
322

    
323
--
324
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
325
--
326

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

    
329

    
330
--
331
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
332
--
333

    
334
ALTER TABLE ONLY batch_download_settings
335
    ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
336

    
337

    
338
--
339
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
340
--
341

    
342
ALTER TABLE ONLY batch
343
    ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
344

    
345

    
346
--
347
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
348
--
349

    
350
ALTER TABLE ONLY batch
351
    ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
352

    
353

    
354
--
355
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
356
--
357

    
358
ALTER TABLE ONLY client_version
359
    ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
360

    
361

    
362
--
363
-- Name: tnrs_Name_submitted_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
364
--
365

    
366
ALTER TABLE ONLY tnrs
367
    ADD CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted");
368

    
369

    
370
--
371
-- Name: tnrs_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace: 
372
--
373

    
374
ALTER TABLE ONLY tnrs
375
    ADD CONSTRAINT tnrs_pkey PRIMARY KEY (batch, "Name_number");
376

    
377

    
378
--
379
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace: 
380
--
381

    
382
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
383

    
384

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

    
389
CREATE UNIQUE INDEX tnrs__valid_match ON tnrs USING btree ("Name_submitted") WHERE is_valid_match;
390

    
391

    
392
--
393
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
394
--
395

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

    
398

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

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

    
405

    
406
--
407
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
408
--
409

    
410
ALTER TABLE ONLY batch
411
    ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
412

    
413

    
414
--
415
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
416
--
417

    
418
ALTER TABLE ONLY batch_download_settings
419
    ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
420

    
421

    
422
--
423
-- Name: tnrs_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
424
--
425

    
426
ALTER TABLE ONLY tnrs
427
    ADD CONSTRAINT tnrs_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
428

    
429

    
430
--
431
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
432
--
433

    
434
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
435
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
436
GRANT ALL ON SCHEMA "TNRS" TO bien;
437
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
438

    
439

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

    
444
REVOKE ALL ON TABLE tnrs FROM PUBLIC;
445
REVOKE ALL ON TABLE tnrs FROM bien;
446
GRANT ALL ON TABLE tnrs TO bien;
447
GRANT SELECT ON TABLE tnrs TO bien_read;
448

    
449

    
450
--
451
-- PostgreSQL database dump complete
452
--
453

    
(8-8/10)