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."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
|
199
|
("*Genus_matched" || ' '::text) || "*Specific_epithet_matched"
|
200
|
FROM (SELECT new.*) new);
|
201
|
|
202
|
new."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
|
203
|
"*Name_matched" || COALESCE((' '::text || "*Name_matched_author"), ''::text)
|
204
|
FROM (SELECT new.*) new);
|
205
|
|
206
|
new.matched_has_accepted = (SELECT
|
207
|
"*Accepted_name" IS NOT NULL
|
208
|
FROM (SELECT new.*) new);
|
209
|
|
210
|
new."__accepted_{genus,specific_epithet}" = (SELECT
|
211
|
regexp_split_to_array("*Accepted_name_species", ' '::text)
|
212
|
FROM (SELECT new.*) new);
|
213
|
|
214
|
new."[accepted_]genus__@DwC__@vegpath.org" = (SELECT
|
215
|
"__accepted_{genus,specific_epithet}"[1]
|
216
|
FROM (SELECT new.*) new);
|
217
|
|
218
|
new."[accepted_]specificEpithet__@DwC__@vegpath.org" = (SELECT
|
219
|
"__accepted_{genus,specific_epithet}"[2]
|
220
|
FROM (SELECT new.*) new);
|
221
|
|
222
|
new.__accepted_infraspecific_label = (SELECT
|
223
|
ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''::text), ' '::text)
|
224
|
FROM (SELECT new.*) new);
|
225
|
|
226
|
new."__accepted_infraspecific_{rank,epithet}" = (SELECT
|
227
|
regexp_split_to_array(__accepted_infraspecific_label, ' '::text)
|
228
|
FROM (SELECT new.*) new);
|
229
|
|
230
|
new."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT
|
231
|
"__accepted_infraspecific_{rank,epithet}"[1]
|
232
|
FROM (SELECT new.*) new);
|
233
|
|
234
|
new."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT
|
235
|
"__accepted_infraspecific_{rank,epithet}"[2]
|
236
|
FROM (SELECT new.*) new);
|
237
|
|
238
|
new."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
|
239
|
"*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text)
|
240
|
FROM (SELECT new.*) new);
|
241
|
|
242
|
new."[scrubbed_]taxonRank__@DwC__@vegpath.org" = (SELECT
|
243
|
CASE
|
244
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
245
|
ELSE "*Name_matched_rank"
|
246
|
END
|
247
|
FROM (SELECT new.*) new);
|
248
|
|
249
|
new."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
|
250
|
CASE
|
251
|
WHEN matched_has_accepted THEN "*Accepted_name_family"
|
252
|
ELSE "*Name_matched_accepted_family"
|
253
|
END
|
254
|
FROM (SELECT new.*) new);
|
255
|
|
256
|
new."[scrubbed_]genus__@DwC__@vegpath.org" = (SELECT
|
257
|
CASE
|
258
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
259
|
ELSE "*Genus_matched"
|
260
|
END
|
261
|
FROM (SELECT new.*) new);
|
262
|
|
263
|
new."[scrubbed_]specificEpithet__@DwC__@vegpath.org" = (SELECT
|
264
|
CASE
|
265
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
266
|
ELSE "*Specific_epithet_matched"
|
267
|
END
|
268
|
FROM (SELECT new.*) new);
|
269
|
|
270
|
new."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
|
271
|
CASE
|
272
|
WHEN matched_has_accepted THEN "*Accepted_name_species"
|
273
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
274
|
END
|
275
|
FROM (SELECT new.*) new);
|
276
|
|
277
|
new."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT
|
278
|
CASE
|
279
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
280
|
ELSE "*Infraspecific_rank"
|
281
|
END
|
282
|
FROM (SELECT new.*) new);
|
283
|
|
284
|
new."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT
|
285
|
CASE
|
286
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
287
|
ELSE "*Infraspecific_epithet_matched"
|
288
|
END
|
289
|
FROM (SELECT new.*) new);
|
290
|
|
291
|
new."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
|
292
|
CASE
|
293
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
294
|
ELSE "*Name_matched"
|
295
|
END
|
296
|
FROM (SELECT new.*) new);
|
297
|
|
298
|
new."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT
|
299
|
CASE
|
300
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
301
|
ELSE "*Name_matched_author"
|
302
|
END
|
303
|
FROM (SELECT new.*) new);
|
304
|
|
305
|
new."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT
|
306
|
CASE
|
307
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
308
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
309
|
END
|
310
|
FROM (SELECT new.*) new);
|
311
|
|
312
|
RETURN new;
|
313
|
END;
|
314
|
$$;
|
315
|
|
316
|
|
317
|
--
|
318
|
-- Name: FUNCTION taxon_match__fill_derived(); Type: COMMENT; Schema: TNRS; Owner: -
|
319
|
--
|
320
|
|
321
|
COMMENT ON FUNCTION taxon_match__fill_derived() IS '
|
322
|
autogenerated, do not edit
|
323
|
|
324
|
to regenerate:
|
325
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
326
|
';
|
327
|
|
328
|
|
329
|
--
|
330
|
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
|
331
|
--
|
332
|
|
333
|
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
|
334
|
LANGUAGE plpgsql
|
335
|
AS $$
|
336
|
BEGIN
|
337
|
IF new.match_num IS NULL THEN
|
338
|
new.match_num = "TNRS".taxon_match__match_num__next();
|
339
|
END IF;
|
340
|
RETURN new;
|
341
|
END;
|
342
|
$$;
|
343
|
|
344
|
|
345
|
--
|
346
|
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
|
347
|
--
|
348
|
|
349
|
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
|
350
|
LANGUAGE sql
|
351
|
AS $$
|
352
|
SELECT nextval('pg_temp.taxon_match__match_num__seq');
|
353
|
$$;
|
354
|
|
355
|
|
356
|
--
|
357
|
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
|
358
|
--
|
359
|
|
360
|
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
|
361
|
LANGUAGE plpgsql
|
362
|
AS $$
|
363
|
BEGIN
|
364
|
INSERT INTO "TNRS".taxon_match_input SELECT new.*;
|
365
|
RETURN NULL;
|
366
|
END;
|
367
|
$$;
|
368
|
|
369
|
|
370
|
--
|
371
|
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
372
|
--
|
373
|
|
374
|
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
|
375
|
LANGUAGE sql IMMUTABLE
|
376
|
AS $_$
|
377
|
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
|
378
|
$_$;
|
379
|
|
380
|
|
381
|
--
|
382
|
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
|
383
|
--
|
384
|
|
385
|
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
|
386
|
LANGUAGE sql IMMUTABLE
|
387
|
AS $$
|
388
|
SELECT ARRAY[
|
389
|
]::text[]
|
390
|
$$;
|
391
|
|
392
|
|
393
|
SET default_tablespace = '';
|
394
|
|
395
|
SET default_with_oids = false;
|
396
|
|
397
|
--
|
398
|
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
399
|
--
|
400
|
|
401
|
CREATE TABLE taxon_match (
|
402
|
batch text DEFAULT now() NOT NULL,
|
403
|
match_num integer NOT NULL,
|
404
|
"*Name_number" integer NOT NULL,
|
405
|
"*Name_submitted" text NOT NULL,
|
406
|
"*Overall_score" double precision,
|
407
|
"*Name_matched" text,
|
408
|
"*Name_matched_rank" text,
|
409
|
"*Name_score" double precision,
|
410
|
"*Name_matched_author" text,
|
411
|
"*Name_matched_url" text,
|
412
|
"*Author_matched" text,
|
413
|
"*Author_score" double precision,
|
414
|
"*Family_matched" text,
|
415
|
"*Family_score" double precision,
|
416
|
"*Name_matched_accepted_family" text,
|
417
|
"*Genus_matched" text,
|
418
|
"*Genus_score" double precision,
|
419
|
"*Specific_epithet_matched" text,
|
420
|
"*Specific_epithet_score" double precision,
|
421
|
"*Infraspecific_rank" text,
|
422
|
"*Infraspecific_epithet_matched" text,
|
423
|
"*Infraspecific_epithet_score" double precision,
|
424
|
"*Infraspecific_rank_2" text,
|
425
|
"*Infraspecific_epithet_2_matched" text,
|
426
|
"*Infraspecific_epithet_2_score" double precision,
|
427
|
"*Annotations" text,
|
428
|
"*Unmatched_terms" text,
|
429
|
"*Taxonomic_status" text,
|
430
|
"*Accepted_name" text,
|
431
|
"*Accepted_name_author" text,
|
432
|
"*Accepted_name_rank" text,
|
433
|
"*Accepted_name_url" text,
|
434
|
"*Accepted_name_species" text,
|
435
|
"*Accepted_name_family" text,
|
436
|
"*Selected" text,
|
437
|
"*Source" text,
|
438
|
"*Warnings" text,
|
439
|
"*Accepted_name_lsid" text,
|
440
|
is_valid_match boolean NOT NULL,
|
441
|
scrubbed_unique_taxon_name text,
|
442
|
"[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
443
|
"[matched_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
444
|
matched_has_accepted boolean,
|
445
|
"__accepted_{genus,specific_epithet}" text[],
|
446
|
"[accepted_]genus__@DwC__@vegpath.org" text,
|
447
|
"[accepted_]specificEpithet__@DwC__@vegpath.org" text,
|
448
|
__accepted_infraspecific_label text,
|
449
|
"__accepted_infraspecific_{rank,epithet}" text[],
|
450
|
"[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
|
451
|
"[accepted_]infraspecificEpithet__@DwC__@vegpath.org" text,
|
452
|
"[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
453
|
"[scrubbed_]taxonRank__@DwC__@vegpath.org" text,
|
454
|
"[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
455
|
"[scrubbed_]genus__@DwC__@vegpath.org" text,
|
456
|
"[scrubbed_]specificEpithet__@DwC__@vegpath.org" text,
|
457
|
"[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
458
|
"[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
|
459
|
"[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" text,
|
460
|
"[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
461
|
"[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
462
|
"[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
463
|
CONSTRAINT "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" CHECK ((NOT ("[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[1]))),
|
464
|
CONSTRAINT "[accepted_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]genus__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[1]))),
|
465
|
CONSTRAINT "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[2]))),
|
466
|
CONSTRAINT "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM ("*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text))))),
|
467
|
CONSTRAINT "[accepted_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet}"[2]))),
|
468
|
CONSTRAINT "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM ("*Name_matched" || COALESCE((' '::text || "*Name_matched_author"), ''::text))))),
|
469
|
CONSTRAINT "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM (("*Genus_matched" || ' '::text) || "*Specific_epithet_matched")))),
|
470
|
CONSTRAINT "[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS DISTINCT FROM
|
471
|
CASE
|
472
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
473
|
ELSE "*Infraspecific_rank"
|
474
|
END))),
|
475
|
CONSTRAINT "[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
476
|
CASE
|
477
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
478
|
ELSE "*Name_matched_author"
|
479
|
END))),
|
480
|
CONSTRAINT "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
481
|
CASE
|
482
|
WHEN matched_has_accepted THEN "*Accepted_name_family"
|
483
|
ELSE "*Name_matched_accepted_family"
|
484
|
END))),
|
485
|
CONSTRAINT "[scrubbed_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]genus__@DwC__@vegpath.org" IS DISTINCT FROM
|
486
|
CASE
|
487
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
488
|
ELSE "*Genus_matched"
|
489
|
END))),
|
490
|
CONSTRAINT "[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
|
491
|
CASE
|
492
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
493
|
ELSE "*Infraspecific_epithet_matched"
|
494
|
END))),
|
495
|
CONSTRAINT "[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
496
|
CASE
|
497
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
498
|
ELSE "*Name_matched"
|
499
|
END))),
|
500
|
CONSTRAINT "[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM
|
501
|
CASE
|
502
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
503
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
504
|
END))),
|
505
|
CONSTRAINT "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
506
|
CASE
|
507
|
WHEN matched_has_accepted THEN "*Accepted_name_species"
|
508
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
509
|
END))),
|
510
|
CONSTRAINT "[scrubbed_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
|
511
|
CASE
|
512
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
513
|
ELSE "*Specific_epithet_matched"
|
514
|
END))),
|
515
|
CONSTRAINT "[scrubbed_]taxonRank__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]taxonRank__@DwC__@vegpath.org" IS DISTINCT FROM
|
516
|
CASE
|
517
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
518
|
ELSE "*Name_matched_rank"
|
519
|
END))),
|
520
|
CONSTRAINT __accepted_infraspecific_label CHECK ((NOT (__accepted_infraspecific_label IS DISTINCT FROM ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''::text), ' '::text)))),
|
521
|
CONSTRAINT "__accepted_infraspecific_{rank,epithet}" CHECK ((NOT ("__accepted_infraspecific_{rank,epithet}" IS DISTINCT FROM regexp_split_to_array(__accepted_infraspecific_label, ' '::text)))),
|
522
|
CONSTRAINT "__accepted_{genus,specific_epithet}" CHECK ((NOT ("__accepted_{genus,specific_epithet}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name_species", ' '::text)))),
|
523
|
CONSTRAINT matched_has_accepted CHECK ((NOT (matched_has_accepted IS DISTINCT FROM ("*Accepted_name" IS NOT NULL))))
|
524
|
);
|
525
|
|
526
|
|
527
|
--
|
528
|
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
|
529
|
--
|
530
|
|
531
|
COMMENT ON TABLE taxon_match IS '
|
532
|
whenever columns are renamed:
|
533
|
SELECT util.derived_cols_sync(''"TNRS".taxon_match'');
|
534
|
|
535
|
to remove columns or add columns at the end:
|
536
|
$ rm=1 inputs/.TNRS/data.sql.run
|
537
|
$ make schemas/remake
|
538
|
|
539
|
to add columns in the middle:
|
540
|
make the changes in inputs/.TNRS/schema.sql
|
541
|
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS
|
542
|
$ make schemas/remake
|
543
|
|
544
|
to populate a new column:
|
545
|
ALTER TABLE "TNRS".taxon_match DISABLE TRIGGER taxon_match__fill; --speeds up update
|
546
|
UPDATE "TNRS".taxon_match SET "col" = value;
|
547
|
-- runtime: 30 min ("5564201 rows affected, 1624829 ms execution time")
|
548
|
CLUSTER "TNRS".taxon_match; -- ensure rows are exported in sorted order
|
549
|
ALTER TABLE "TNRS".taxon_match ENABLE TRIGGER taxon_match__fill;
|
550
|
VACUUM ANALYZE "TNRS".taxon_match --remove previous rows; runtime: 1.5 min ("92633 ms")
|
551
|
|
552
|
to add a constraint: runtime: 3 min ("173620 ms")
|
553
|
';
|
554
|
|
555
|
|
556
|
--
|
557
|
-- Name: COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
558
|
--
|
559
|
|
560
|
COMMENT ON COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
561
|
derived column; = ("*Genus_matched" || '' ''::text) || "*Specific_epithet_matched"
|
562
|
|
563
|
to modify expr:
|
564
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$"*Genus_matched" || '' ''::text || "*Specific_epithet_matched"$$)::util.derived_col_def);
|
565
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
566
|
|
567
|
to rename:
|
568
|
# rename column
|
569
|
# rename CHECK constraint
|
570
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
571
|
';
|
572
|
|
573
|
|
574
|
--
|
575
|
-- Name: COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
576
|
--
|
577
|
|
578
|
COMMENT ON COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
579
|
derived column; = "*Name_matched" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)
|
580
|
|
581
|
to modify expr:
|
582
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[matched_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$"*Name_matched" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)$$)::util.derived_col_def);
|
583
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
584
|
|
585
|
to rename:
|
586
|
# rename column
|
587
|
# rename CHECK constraint
|
588
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
589
|
';
|
590
|
|
591
|
|
592
|
--
|
593
|
-- Name: COLUMN taxon_match.matched_has_accepted; Type: COMMENT; Schema: TNRS; Owner: -
|
594
|
--
|
595
|
|
596
|
COMMENT ON COLUMN taxon_match.matched_has_accepted IS '
|
597
|
derived column; = "*Accepted_name" IS NOT NULL
|
598
|
|
599
|
to modify expr:
|
600
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''matched_has_accepted'')::util.col, $$"*Accepted_name" IS NOT NULL$$)::util.derived_col_def);
|
601
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
602
|
|
603
|
to rename:
|
604
|
# rename column
|
605
|
# rename CHECK constraint
|
606
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
607
|
';
|
608
|
|
609
|
|
610
|
--
|
611
|
-- Name: COLUMN taxon_match."__accepted_{genus,specific_epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
|
612
|
--
|
613
|
|
614
|
COMMENT ON COLUMN taxon_match."__accepted_{genus,specific_epithet}" IS '
|
615
|
derived column; = regexp_split_to_array("*Accepted_name_species", '' ''::text)
|
616
|
|
617
|
to modify expr:
|
618
|
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);
|
619
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
620
|
|
621
|
to rename:
|
622
|
# rename column
|
623
|
# rename CHECK constraint
|
624
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
625
|
';
|
626
|
|
627
|
|
628
|
--
|
629
|
-- Name: COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
630
|
--
|
631
|
|
632
|
COMMENT ON COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org" IS '
|
633
|
derived column; = "__accepted_{genus,specific_epithet}"[1]
|
634
|
|
635
|
to modify expr:
|
636
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]genus__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[1]$$)::util.derived_col_def);
|
637
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
638
|
|
639
|
to rename:
|
640
|
# rename column
|
641
|
# rename CHECK constraint
|
642
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
643
|
';
|
644
|
|
645
|
|
646
|
--
|
647
|
-- Name: COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
648
|
--
|
649
|
|
650
|
COMMENT ON COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org" IS '
|
651
|
derived column; = "__accepted_{genus,specific_epithet}"[2]
|
652
|
|
653
|
to modify expr:
|
654
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet}"[2]$$)::util.derived_col_def);
|
655
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
656
|
|
657
|
to rename:
|
658
|
# rename column
|
659
|
# rename CHECK constraint
|
660
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
661
|
';
|
662
|
|
663
|
|
664
|
--
|
665
|
-- Name: COLUMN taxon_match.__accepted_infraspecific_label; Type: COMMENT; Schema: TNRS; Owner: -
|
666
|
--
|
667
|
|
668
|
COMMENT ON COLUMN taxon_match.__accepted_infraspecific_label IS '
|
669
|
derived column; = ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''''::text), '' ''::text)
|
670
|
|
671
|
to modify expr:
|
672
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_infraspecific_label'')::util.col, $$ltrim(NULLIF(util.remove_prefix("*Accepted_name_species", "*Accepted_name", require := true), ''''::text), '' ''::text)$$)::util.derived_col_def);
|
673
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
674
|
|
675
|
to rename:
|
676
|
# rename column
|
677
|
# rename CHECK constraint
|
678
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
679
|
';
|
680
|
|
681
|
|
682
|
--
|
683
|
-- Name: COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
|
684
|
--
|
685
|
|
686
|
COMMENT ON COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}" IS '
|
687
|
derived column; = regexp_split_to_array(__accepted_infraspecific_label, '' ''::text)
|
688
|
|
689
|
to modify expr:
|
690
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_infraspecific_{rank,epithet}'')::util.col, $$regexp_split_to_array(__accepted_infraspecific_label, '' ''::text)$$)::util.derived_col_def);
|
691
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
692
|
|
693
|
to rename:
|
694
|
# rename column
|
695
|
# rename CHECK constraint
|
696
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
697
|
';
|
698
|
|
699
|
|
700
|
--
|
701
|
-- Name: COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
702
|
--
|
703
|
|
704
|
COMMENT ON COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
|
705
|
derived column; = "__accepted_infraspecific_{rank,epithet}"[1]
|
706
|
|
707
|
to modify expr:
|
708
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col, $$"__accepted_infraspecific_{rank,epithet}"[1]$$)::util.derived_col_def);
|
709
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
710
|
|
711
|
to rename:
|
712
|
# rename column
|
713
|
# rename CHECK constraint
|
714
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
715
|
';
|
716
|
|
717
|
|
718
|
--
|
719
|
-- Name: COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
720
|
--
|
721
|
|
722
|
COMMENT ON COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS '
|
723
|
derived column; = "__accepted_infraspecific_{rank,epithet}"[2]
|
724
|
|
725
|
to modify expr:
|
726
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_infraspecific_{rank,epithet}"[2]$$)::util.derived_col_def);
|
727
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
728
|
|
729
|
to rename:
|
730
|
# rename column
|
731
|
# rename CHECK constraint
|
732
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
733
|
';
|
734
|
|
735
|
|
736
|
--
|
737
|
-- Name: COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
738
|
--
|
739
|
|
740
|
COMMENT ON COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
741
|
derived column; = "*Accepted_name" || COALESCE(('' ''::text || "*Accepted_name_author"), ''''::text)
|
742
|
|
743
|
to modify expr:
|
744
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$"*Accepted_name" || COALESCE(('' ''::text || "*Accepted_name_author"), ''''::text)$$)::util.derived_col_def);
|
745
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
746
|
|
747
|
to rename:
|
748
|
# rename column
|
749
|
# rename CHECK constraint
|
750
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
751
|
';
|
752
|
|
753
|
|
754
|
--
|
755
|
-- Name: COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
756
|
--
|
757
|
|
758
|
COMMENT ON COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org" IS '
|
759
|
derived column; = CASE
|
760
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
761
|
ELSE "*Name_matched_rank"
|
762
|
END
|
763
|
|
764
|
to modify expr:
|
765
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]taxonRank__@DwC__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "*Accepted_name_rank" ELSE "*Name_matched_rank" END$$)::util.derived_col_def);
|
766
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
767
|
|
768
|
to rename:
|
769
|
# rename column
|
770
|
# rename CHECK constraint
|
771
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
772
|
';
|
773
|
|
774
|
|
775
|
--
|
776
|
-- Name: COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
777
|
--
|
778
|
|
779
|
COMMENT ON COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
780
|
derived column; = CASE
|
781
|
WHEN matched_has_accepted THEN "*Accepted_name_family"
|
782
|
ELSE "*Name_matched_accepted_family"
|
783
|
END
|
784
|
|
785
|
to modify expr:
|
786
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "*Accepted_name_family" ELSE "*Name_matched_accepted_family" END$$)::util.derived_col_def);
|
787
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
788
|
|
789
|
to rename:
|
790
|
# rename column
|
791
|
# rename CHECK constraint
|
792
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
793
|
';
|
794
|
|
795
|
|
796
|
--
|
797
|
-- Name: COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
798
|
--
|
799
|
|
800
|
COMMENT ON COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org" IS '
|
801
|
derived column; = CASE
|
802
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
803
|
ELSE "*Genus_matched"
|
804
|
END
|
805
|
|
806
|
to modify expr:
|
807
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]genus__@DwC__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org" ELSE "*Genus_matched" END$$)::util.derived_col_def);
|
808
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
809
|
|
810
|
to rename:
|
811
|
# rename column
|
812
|
# rename CHECK constraint
|
813
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
814
|
';
|
815
|
|
816
|
|
817
|
--
|
818
|
-- Name: COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
819
|
--
|
820
|
|
821
|
COMMENT ON COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS '
|
822
|
derived column; = CASE
|
823
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
824
|
ELSE "*Specific_epithet_matched"
|
825
|
END
|
826
|
|
827
|
to modify expr:
|
828
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org" ELSE "*Specific_epithet_matched" END$$)::util.derived_col_def);
|
829
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
830
|
|
831
|
to rename:
|
832
|
# rename column
|
833
|
# rename CHECK constraint
|
834
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
835
|
';
|
836
|
|
837
|
|
838
|
--
|
839
|
-- Name: COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
840
|
--
|
841
|
|
842
|
COMMENT ON COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
843
|
derived column; = CASE
|
844
|
WHEN matched_has_accepted THEN "*Accepted_name_species"
|
845
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
846
|
END
|
847
|
|
848
|
to modify expr:
|
849
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "*Accepted_name_species" ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" END$$)::util.derived_col_def);
|
850
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
851
|
|
852
|
to rename:
|
853
|
# rename column
|
854
|
# rename CHECK constraint
|
855
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
856
|
';
|
857
|
|
858
|
|
859
|
--
|
860
|
-- Name: COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
861
|
--
|
862
|
|
863
|
COMMENT ON COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
|
864
|
derived column; = CASE
|
865
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
866
|
ELSE "*Infraspecific_rank"
|
867
|
END
|
868
|
|
869
|
to modify expr:
|
870
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" ELSE "*Infraspecific_rank" END$$)::util.derived_col_def);
|
871
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
872
|
|
873
|
to rename:
|
874
|
# rename column
|
875
|
# rename CHECK constraint
|
876
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
877
|
';
|
878
|
|
879
|
|
880
|
--
|
881
|
-- Name: COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
882
|
--
|
883
|
|
884
|
COMMENT ON COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS '
|
885
|
derived column; = CASE
|
886
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
887
|
ELSE "*Infraspecific_epithet_matched"
|
888
|
END
|
889
|
|
890
|
to modify expr:
|
891
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org" ELSE "*Infraspecific_epithet_matched" END$$)::util.derived_col_def);
|
892
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
893
|
|
894
|
to rename:
|
895
|
# rename column
|
896
|
# rename CHECK constraint
|
897
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
898
|
';
|
899
|
|
900
|
|
901
|
--
|
902
|
-- Name: COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
903
|
--
|
904
|
|
905
|
COMMENT ON COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
906
|
derived column; = CASE
|
907
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
908
|
ELSE "*Name_matched"
|
909
|
END
|
910
|
|
911
|
to modify expr:
|
912
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "*Accepted_name" ELSE "*Name_matched" END$$)::util.derived_col_def);
|
913
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
914
|
|
915
|
to rename:
|
916
|
# rename column
|
917
|
# rename CHECK constraint
|
918
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
919
|
';
|
920
|
|
921
|
|
922
|
--
|
923
|
-- Name: COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
924
|
--
|
925
|
|
926
|
COMMENT ON COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
927
|
derived column; = CASE
|
928
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
929
|
ELSE "*Name_matched_author"
|
930
|
END
|
931
|
|
932
|
to modify expr:
|
933
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "*Accepted_name_author" ELSE "*Name_matched_author" END$$)::util.derived_col_def);
|
934
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
935
|
|
936
|
to rename:
|
937
|
# rename column
|
938
|
# rename CHECK constraint
|
939
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
940
|
';
|
941
|
|
942
|
|
943
|
--
|
944
|
-- Name: COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
945
|
--
|
946
|
|
947
|
COMMENT ON COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
948
|
derived column; = CASE
|
949
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
950
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
951
|
END
|
952
|
|
953
|
to modify expr:
|
954
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$CASE WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" END$$)::util.derived_col_def);
|
955
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
956
|
|
957
|
to rename:
|
958
|
# rename column
|
959
|
# rename CHECK constraint
|
960
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
961
|
';
|
962
|
|
963
|
|
964
|
--
|
965
|
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
|
966
|
--
|
967
|
|
968
|
CREATE VIEW taxon_best_match AS
|
969
|
SELECT taxon_match.batch,
|
970
|
taxon_match.match_num,
|
971
|
taxon_match."*Name_number",
|
972
|
taxon_match."*Name_submitted",
|
973
|
taxon_match."*Overall_score",
|
974
|
taxon_match."*Name_matched",
|
975
|
taxon_match."*Name_matched_rank",
|
976
|
taxon_match."*Name_score",
|
977
|
taxon_match."*Name_matched_author",
|
978
|
taxon_match."*Name_matched_url",
|
979
|
taxon_match."*Author_matched",
|
980
|
taxon_match."*Author_score",
|
981
|
taxon_match."*Family_matched",
|
982
|
taxon_match."*Family_score",
|
983
|
taxon_match."*Name_matched_accepted_family",
|
984
|
taxon_match."*Genus_matched",
|
985
|
taxon_match."*Genus_score",
|
986
|
taxon_match."*Specific_epithet_matched",
|
987
|
taxon_match."*Specific_epithet_score",
|
988
|
taxon_match."*Infraspecific_rank",
|
989
|
taxon_match."*Infraspecific_epithet_matched",
|
990
|
taxon_match."*Infraspecific_epithet_score",
|
991
|
taxon_match."*Infraspecific_rank_2",
|
992
|
taxon_match."*Infraspecific_epithet_2_matched",
|
993
|
taxon_match."*Infraspecific_epithet_2_score",
|
994
|
taxon_match."*Annotations",
|
995
|
taxon_match."*Unmatched_terms",
|
996
|
taxon_match."*Taxonomic_status",
|
997
|
taxon_match."*Accepted_name",
|
998
|
taxon_match."*Accepted_name_author",
|
999
|
taxon_match."*Accepted_name_rank",
|
1000
|
taxon_match."*Accepted_name_url",
|
1001
|
taxon_match."*Accepted_name_species",
|
1002
|
taxon_match."*Accepted_name_family",
|
1003
|
taxon_match."*Selected",
|
1004
|
taxon_match."*Source",
|
1005
|
taxon_match."*Warnings",
|
1006
|
taxon_match."*Accepted_name_lsid",
|
1007
|
taxon_match.is_valid_match,
|
1008
|
taxon_match.scrubbed_unique_taxon_name,
|
1009
|
taxon_match."__accepted_{genus,specific_epithet}",
|
1010
|
taxon_match."[accepted_]genus__@DwC__@vegpath.org",
|
1011
|
taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1012
|
taxon_match.__accepted_infraspecific_label,
|
1013
|
taxon_match."__accepted_infraspecific_{rank,epithet}",
|
1014
|
taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1015
|
taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1016
|
taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1017
|
taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1018
|
FROM taxon_match
|
1019
|
WHERE (taxon_match."*Selected" = 'true'::text);
|
1020
|
|
1021
|
|
1022
|
--
|
1023
|
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
|
1024
|
--
|
1025
|
|
1026
|
COMMENT ON VIEW taxon_best_match IS '
|
1027
|
to modify:
|
1028
|
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
|
1029
|
SELECT __
|
1030
|
$$);
|
1031
|
';
|
1032
|
|
1033
|
|
1034
|
--
|
1035
|
-- Name: MatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
|
1036
|
--
|
1037
|
|
1038
|
CREATE VIEW "MatchedTaxon" AS
|
1039
|
SELECT taxon_best_match.batch,
|
1040
|
taxon_best_match.match_num,
|
1041
|
taxon_best_match."*Name_number",
|
1042
|
taxon_best_match."*Name_submitted",
|
1043
|
taxon_best_match."*Overall_score",
|
1044
|
taxon_best_match."*Name_matched",
|
1045
|
taxon_best_match."*Name_matched_rank",
|
1046
|
taxon_best_match."*Name_score",
|
1047
|
taxon_best_match."*Name_matched_author",
|
1048
|
taxon_best_match."*Name_matched_url",
|
1049
|
taxon_best_match."*Author_matched",
|
1050
|
taxon_best_match."*Author_score",
|
1051
|
taxon_best_match."*Family_matched",
|
1052
|
taxon_best_match."*Family_score",
|
1053
|
taxon_best_match."*Name_matched_accepted_family",
|
1054
|
taxon_best_match."*Genus_matched",
|
1055
|
taxon_best_match."*Genus_score",
|
1056
|
taxon_best_match."*Specific_epithet_matched",
|
1057
|
taxon_best_match."*Specific_epithet_score",
|
1058
|
taxon_best_match."*Infraspecific_rank",
|
1059
|
taxon_best_match."*Infraspecific_epithet_matched",
|
1060
|
taxon_best_match."*Infraspecific_epithet_score",
|
1061
|
taxon_best_match."*Infraspecific_rank_2",
|
1062
|
taxon_best_match."*Infraspecific_epithet_2_matched",
|
1063
|
taxon_best_match."*Infraspecific_epithet_2_score",
|
1064
|
taxon_best_match."*Annotations",
|
1065
|
taxon_best_match."*Unmatched_terms",
|
1066
|
taxon_best_match."*Taxonomic_status",
|
1067
|
taxon_best_match."*Accepted_name",
|
1068
|
taxon_best_match."*Accepted_name_author",
|
1069
|
taxon_best_match."*Accepted_name_rank",
|
1070
|
taxon_best_match."*Accepted_name_url",
|
1071
|
taxon_best_match."*Accepted_name_species",
|
1072
|
taxon_best_match."*Accepted_name_family",
|
1073
|
taxon_best_match."*Selected",
|
1074
|
taxon_best_match."*Source",
|
1075
|
taxon_best_match."*Warnings",
|
1076
|
taxon_best_match."*Accepted_name_lsid",
|
1077
|
taxon_best_match.is_valid_match,
|
1078
|
taxon_best_match.scrubbed_unique_taxon_name,
|
1079
|
taxon_best_match."__accepted_{genus,specific_epithet}",
|
1080
|
taxon_best_match."[accepted_]genus__@DwC__@vegpath.org",
|
1081
|
taxon_best_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1082
|
taxon_best_match.__accepted_infraspecific_label,
|
1083
|
taxon_best_match."__accepted_infraspecific_{rank,epithet}",
|
1084
|
taxon_best_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1085
|
taxon_best_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1086
|
taxon_best_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1087
|
taxon_best_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1088
|
map_taxonomic_status(taxon_best_match."*Taxonomic_status", taxon_best_match."*Accepted_name") AS "taxonomicStatus",
|
1089
|
CASE
|
1090
|
WHEN (taxon_best_match."*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name_family", taxon_best_match."*Unmatched_terms")
|
1091
|
WHEN (taxon_best_match."*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, taxon_best_match."*Accepted_name", taxon_best_match."*Unmatched_terms")
|
1092
|
ELSE taxon_best_match."*Accepted_name_species"
|
1093
|
END AS accepted_morphospecies_binomial
|
1094
|
FROM taxon_best_match;
|
1095
|
|
1096
|
|
1097
|
--
|
1098
|
-- Name: VIEW "MatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
|
1099
|
--
|
1100
|
|
1101
|
COMMENT ON VIEW "MatchedTaxon" IS '
|
1102
|
to modify:
|
1103
|
SELECT util.recreate_view(''"TNRS"."MatchedTaxon"'', $$
|
1104
|
SELECT __
|
1105
|
$$);
|
1106
|
';
|
1107
|
|
1108
|
|
1109
|
--
|
1110
|
-- Name: ValidMatchedTaxon; Type: VIEW; Schema: TNRS; Owner: -
|
1111
|
--
|
1112
|
|
1113
|
CREATE VIEW "ValidMatchedTaxon" AS
|
1114
|
SELECT "MatchedTaxon".batch,
|
1115
|
"MatchedTaxon".match_num,
|
1116
|
"MatchedTaxon"."*Name_number",
|
1117
|
"MatchedTaxon"."*Name_submitted",
|
1118
|
"MatchedTaxon"."*Overall_score",
|
1119
|
"MatchedTaxon"."*Name_matched",
|
1120
|
"MatchedTaxon"."*Name_matched_rank",
|
1121
|
"MatchedTaxon"."*Name_score",
|
1122
|
"MatchedTaxon"."*Name_matched_author",
|
1123
|
"MatchedTaxon"."*Name_matched_url",
|
1124
|
"MatchedTaxon"."*Author_matched",
|
1125
|
"MatchedTaxon"."*Author_score",
|
1126
|
"MatchedTaxon"."*Family_matched",
|
1127
|
"MatchedTaxon"."*Family_score",
|
1128
|
"MatchedTaxon"."*Name_matched_accepted_family",
|
1129
|
"MatchedTaxon"."*Genus_matched",
|
1130
|
"MatchedTaxon"."*Genus_score",
|
1131
|
"MatchedTaxon"."*Specific_epithet_matched",
|
1132
|
"MatchedTaxon"."*Specific_epithet_score",
|
1133
|
"MatchedTaxon"."*Infraspecific_rank",
|
1134
|
"MatchedTaxon"."*Infraspecific_epithet_matched",
|
1135
|
"MatchedTaxon"."*Infraspecific_epithet_score",
|
1136
|
"MatchedTaxon"."*Infraspecific_rank_2",
|
1137
|
"MatchedTaxon"."*Infraspecific_epithet_2_matched",
|
1138
|
"MatchedTaxon"."*Infraspecific_epithet_2_score",
|
1139
|
"MatchedTaxon"."*Annotations",
|
1140
|
"MatchedTaxon"."*Unmatched_terms",
|
1141
|
"MatchedTaxon"."*Taxonomic_status",
|
1142
|
"MatchedTaxon"."*Accepted_name",
|
1143
|
"MatchedTaxon"."*Accepted_name_author",
|
1144
|
"MatchedTaxon"."*Accepted_name_rank",
|
1145
|
"MatchedTaxon"."*Accepted_name_url",
|
1146
|
"MatchedTaxon"."*Accepted_name_species",
|
1147
|
"MatchedTaxon"."*Accepted_name_family",
|
1148
|
"MatchedTaxon"."*Selected",
|
1149
|
"MatchedTaxon"."*Source",
|
1150
|
"MatchedTaxon"."*Warnings",
|
1151
|
"MatchedTaxon"."*Accepted_name_lsid",
|
1152
|
"MatchedTaxon".is_valid_match,
|
1153
|
"MatchedTaxon".scrubbed_unique_taxon_name,
|
1154
|
"MatchedTaxon"."__accepted_{genus,specific_epithet}",
|
1155
|
"MatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
|
1156
|
"MatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1157
|
"MatchedTaxon".__accepted_infraspecific_label,
|
1158
|
"MatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
|
1159
|
"MatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1160
|
"MatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1161
|
"MatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1162
|
"MatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1163
|
"MatchedTaxon"."taxonomicStatus",
|
1164
|
"MatchedTaxon".accepted_morphospecies_binomial
|
1165
|
FROM "MatchedTaxon"
|
1166
|
WHERE "MatchedTaxon".is_valid_match;
|
1167
|
|
1168
|
|
1169
|
--
|
1170
|
-- Name: VIEW "ValidMatchedTaxon"; Type: COMMENT; Schema: TNRS; Owner: -
|
1171
|
--
|
1172
|
|
1173
|
COMMENT ON VIEW "ValidMatchedTaxon" IS '
|
1174
|
to update, use * as the column list
|
1175
|
';
|
1176
|
|
1177
|
|
1178
|
--
|
1179
|
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
1180
|
--
|
1181
|
|
1182
|
CREATE TABLE batch (
|
1183
|
id text NOT NULL,
|
1184
|
id_by_time text,
|
1185
|
time_submitted timestamp with time zone DEFAULT now(),
|
1186
|
client_version text
|
1187
|
);
|
1188
|
|
1189
|
|
1190
|
--
|
1191
|
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
1192
|
--
|
1193
|
|
1194
|
CREATE TABLE batch_download_settings (
|
1195
|
id text NOT NULL,
|
1196
|
"E-mail" text,
|
1197
|
"Id" text,
|
1198
|
"Job type" text,
|
1199
|
"Contains Id" boolean,
|
1200
|
"Start time" text,
|
1201
|
"Finish time" text,
|
1202
|
"TNRS version" text,
|
1203
|
"Sources selected" text,
|
1204
|
"Match threshold" double precision,
|
1205
|
"Classification" text,
|
1206
|
"Allow partial matches?" boolean,
|
1207
|
"Sort by source" boolean,
|
1208
|
"Constrain by higher taxonomy" boolean
|
1209
|
);
|
1210
|
|
1211
|
|
1212
|
--
|
1213
|
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
|
1214
|
--
|
1215
|
|
1216
|
COMMENT ON TABLE batch_download_settings IS '
|
1217
|
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
|
1218
|
';
|
1219
|
|
1220
|
|
1221
|
--
|
1222
|
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
1223
|
--
|
1224
|
|
1225
|
CREATE TABLE client_version (
|
1226
|
id text NOT NULL,
|
1227
|
global_rev integer NOT NULL,
|
1228
|
"/lib/tnrs.py rev" integer,
|
1229
|
"/bin/tnrs_db rev" integer
|
1230
|
);
|
1231
|
|
1232
|
|
1233
|
--
|
1234
|
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
|
1235
|
--
|
1236
|
|
1237
|
COMMENT ON TABLE client_version IS '
|
1238
|
contains svn revisions
|
1239
|
';
|
1240
|
|
1241
|
|
1242
|
--
|
1243
|
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
|
1244
|
--
|
1245
|
|
1246
|
COMMENT ON COLUMN client_version.global_rev IS '
|
1247
|
from `svn info .` > Last Changed Rev
|
1248
|
';
|
1249
|
|
1250
|
|
1251
|
--
|
1252
|
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
1253
|
--
|
1254
|
|
1255
|
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
|
1256
|
from `svn info lib/tnrs.py` > Last Changed Rev
|
1257
|
';
|
1258
|
|
1259
|
|
1260
|
--
|
1261
|
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
1262
|
--
|
1263
|
|
1264
|
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
|
1265
|
from `svn info bin/tnrs_db` > Last Changed Rev
|
1266
|
';
|
1267
|
|
1268
|
|
1269
|
--
|
1270
|
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
|
1271
|
--
|
1272
|
|
1273
|
CREATE VIEW taxon_match_input AS
|
1274
|
SELECT taxon_match."*Name_number" AS "Name_number",
|
1275
|
taxon_match."*Name_submitted" AS "Name_submitted",
|
1276
|
taxon_match."*Overall_score" AS "Overall_score",
|
1277
|
taxon_match."*Name_matched" AS "Name_matched",
|
1278
|
taxon_match."*Name_matched_rank" AS "Name_matched_rank",
|
1279
|
taxon_match."*Name_score" AS "Name_score",
|
1280
|
taxon_match."*Name_matched_author" AS "Name_matched_author",
|
1281
|
taxon_match."*Name_matched_url" AS "Name_matched_url",
|
1282
|
taxon_match."*Author_matched" AS "Author_matched",
|
1283
|
taxon_match."*Author_score" AS "Author_score",
|
1284
|
taxon_match."*Family_matched" AS "Family_matched",
|
1285
|
taxon_match."*Family_score" AS "Family_score",
|
1286
|
taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
|
1287
|
taxon_match."*Genus_matched" AS "Genus_matched",
|
1288
|
taxon_match."*Genus_score" AS "Genus_score",
|
1289
|
taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
|
1290
|
taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
|
1291
|
taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
|
1292
|
taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
|
1293
|
taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
|
1294
|
taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
|
1295
|
taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
|
1296
|
taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
|
1297
|
taxon_match."*Annotations" AS "Annotations",
|
1298
|
taxon_match."*Unmatched_terms" AS "Unmatched_terms",
|
1299
|
taxon_match."*Taxonomic_status" AS "Taxonomic_status",
|
1300
|
taxon_match."*Accepted_name" AS "Accepted_name",
|
1301
|
taxon_match."*Accepted_name_author" AS "Accepted_name_author",
|
1302
|
taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
|
1303
|
taxon_match."*Accepted_name_url" AS "Accepted_name_url",
|
1304
|
taxon_match."*Accepted_name_species" AS "Accepted_name_species",
|
1305
|
taxon_match."*Accepted_name_family" AS "Accepted_name_family",
|
1306
|
taxon_match."*Selected" AS "Selected",
|
1307
|
taxon_match."*Source" AS "Source",
|
1308
|
taxon_match."*Warnings" AS "Warnings",
|
1309
|
taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
|
1310
|
FROM taxon_match;
|
1311
|
|
1312
|
|
1313
|
--
|
1314
|
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
1315
|
--
|
1316
|
|
1317
|
CREATE TABLE taxon_match_input__copy_to (
|
1318
|
"Name_number" integer,
|
1319
|
"Name_submitted" text,
|
1320
|
"Overall_score" double precision,
|
1321
|
"Name_matched" text,
|
1322
|
"Name_matched_rank" text,
|
1323
|
"Name_score" double precision,
|
1324
|
"Name_matched_author" text,
|
1325
|
"Name_matched_url" text,
|
1326
|
"Author_matched" text,
|
1327
|
"Author_score" double precision,
|
1328
|
"Family_matched" text,
|
1329
|
"Family_score" double precision,
|
1330
|
"Name_matched_accepted_family" text,
|
1331
|
"Genus_matched" text,
|
1332
|
"Genus_score" double precision,
|
1333
|
"Specific_epithet_matched" text,
|
1334
|
"Specific_epithet_score" double precision,
|
1335
|
"Infraspecific_rank" text,
|
1336
|
"Infraspecific_epithet_matched" text,
|
1337
|
"Infraspecific_epithet_score" double precision,
|
1338
|
"Infraspecific_rank_2" text,
|
1339
|
"Infraspecific_epithet_2_matched" text,
|
1340
|
"Infraspecific_epithet_2_score" double precision,
|
1341
|
"Annotations" text,
|
1342
|
"Unmatched_terms" text,
|
1343
|
"Taxonomic_status" text,
|
1344
|
"Accepted_name" text,
|
1345
|
"Accepted_name_author" text,
|
1346
|
"Accepted_name_rank" text,
|
1347
|
"Accepted_name_url" text,
|
1348
|
"Accepted_name_species" text,
|
1349
|
"Accepted_name_family" text,
|
1350
|
"Selected" text,
|
1351
|
"Source" text,
|
1352
|
"Warnings" text,
|
1353
|
"Accepted_name_lsid" text
|
1354
|
);
|
1355
|
|
1356
|
|
1357
|
--
|
1358
|
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: VIEW; Schema: TNRS; Owner: -
|
1359
|
--
|
1360
|
|
1361
|
CREATE VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" AS
|
1362
|
SELECT taxon_match."*Name_submitted" AS scrubbed_unique_taxon_name,
|
1363
|
taxon_match."*Name_matched_rank" AS scrubbed_taxon_rank,
|
1364
|
COALESCE(taxon_match."*Name_matched_accepted_family", taxon_match."*Family_matched") AS scrubbed_family,
|
1365
|
taxon_match."*Genus_matched" AS scrubbed_genus,
|
1366
|
taxon_match."*Specific_epithet_matched" AS scrubbed_specific_epithet,
|
1367
|
taxon_match."*Infraspecific_rank" AS scrubbed_infraspecific_rank,
|
1368
|
taxon_match."*Infraspecific_epithet_matched" AS scrubbed_infraspecific_epithet,
|
1369
|
taxon_match."*Name_matched_author" AS scrubbed_author,
|
1370
|
taxon_match."*Name_matched" AS scrubbed_taxon_name_no_author,
|
1371
|
(taxon_match."*Name_matched" || COALESCE((' '::text || taxon_match."*Name_matched_author"), ''::text)) AS scrubbed_taxon_name_with_author
|
1372
|
FROM taxon_match;
|
1373
|
|
1374
|
|
1375
|
--
|
1376
|
-- Name: VIEW "taxon_scrub.scrubbed_unique_taxon_name.*"; Type: COMMENT; Schema: TNRS; Owner: -
|
1377
|
--
|
1378
|
|
1379
|
COMMENT ON VIEW "taxon_scrub.scrubbed_unique_taxon_name.*" IS '
|
1380
|
to modify:
|
1381
|
SELECT util.recreate_view(''"TNRS"."taxon_scrub.scrubbed_unique_taxon_name.*"'', $$
|
1382
|
SELECT __
|
1383
|
$$);
|
1384
|
|
1385
|
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.
|
1386
|
';
|
1387
|
|
1388
|
|
1389
|
--
|
1390
|
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
|
1391
|
--
|
1392
|
|
1393
|
CREATE VIEW taxon_scrub AS
|
1394
|
SELECT "ValidMatchedTaxon".scrubbed_unique_taxon_name,
|
1395
|
"ValidMatchedTaxon".batch,
|
1396
|
"ValidMatchedTaxon".match_num,
|
1397
|
"ValidMatchedTaxon"."*Name_number",
|
1398
|
"ValidMatchedTaxon"."*Name_submitted",
|
1399
|
"ValidMatchedTaxon"."*Overall_score",
|
1400
|
"ValidMatchedTaxon"."*Name_matched",
|
1401
|
"ValidMatchedTaxon"."*Name_matched_rank",
|
1402
|
"ValidMatchedTaxon"."*Name_score",
|
1403
|
"ValidMatchedTaxon"."*Name_matched_author",
|
1404
|
"ValidMatchedTaxon"."*Name_matched_url",
|
1405
|
"ValidMatchedTaxon"."*Author_matched",
|
1406
|
"ValidMatchedTaxon"."*Author_score",
|
1407
|
"ValidMatchedTaxon"."*Family_matched",
|
1408
|
"ValidMatchedTaxon"."*Family_score",
|
1409
|
"ValidMatchedTaxon"."*Name_matched_accepted_family",
|
1410
|
"ValidMatchedTaxon"."*Genus_matched",
|
1411
|
"ValidMatchedTaxon"."*Genus_score",
|
1412
|
"ValidMatchedTaxon"."*Specific_epithet_matched",
|
1413
|
"ValidMatchedTaxon"."*Specific_epithet_score",
|
1414
|
"ValidMatchedTaxon"."*Infraspecific_rank",
|
1415
|
"ValidMatchedTaxon"."*Infraspecific_epithet_matched",
|
1416
|
"ValidMatchedTaxon"."*Infraspecific_epithet_score",
|
1417
|
"ValidMatchedTaxon"."*Infraspecific_rank_2",
|
1418
|
"ValidMatchedTaxon"."*Infraspecific_epithet_2_matched",
|
1419
|
"ValidMatchedTaxon"."*Infraspecific_epithet_2_score",
|
1420
|
"ValidMatchedTaxon"."*Annotations",
|
1421
|
"ValidMatchedTaxon"."*Unmatched_terms",
|
1422
|
"ValidMatchedTaxon"."*Taxonomic_status",
|
1423
|
"ValidMatchedTaxon"."*Accepted_name",
|
1424
|
"ValidMatchedTaxon"."*Accepted_name_author",
|
1425
|
"ValidMatchedTaxon"."*Accepted_name_rank",
|
1426
|
"ValidMatchedTaxon"."*Accepted_name_url",
|
1427
|
"ValidMatchedTaxon"."*Accepted_name_species",
|
1428
|
"ValidMatchedTaxon"."*Accepted_name_family",
|
1429
|
"ValidMatchedTaxon"."*Selected",
|
1430
|
"ValidMatchedTaxon"."*Source",
|
1431
|
"ValidMatchedTaxon"."*Warnings",
|
1432
|
"ValidMatchedTaxon"."*Accepted_name_lsid",
|
1433
|
"ValidMatchedTaxon".is_valid_match,
|
1434
|
"ValidMatchedTaxon"."__accepted_{genus,specific_epithet}",
|
1435
|
"ValidMatchedTaxon"."[accepted_]genus__@DwC__@vegpath.org",
|
1436
|
"ValidMatchedTaxon"."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1437
|
"ValidMatchedTaxon".__accepted_infraspecific_label,
|
1438
|
"ValidMatchedTaxon"."__accepted_infraspecific_{rank,epithet}",
|
1439
|
"ValidMatchedTaxon"."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1440
|
"ValidMatchedTaxon"."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1441
|
"ValidMatchedTaxon"."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1442
|
"ValidMatchedTaxon"."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1443
|
"ValidMatchedTaxon"."taxonomicStatus",
|
1444
|
"ValidMatchedTaxon".accepted_morphospecies_binomial,
|
1445
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_rank,
|
1446
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_family,
|
1447
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus,
|
1448
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet,
|
1449
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_rank,
|
1450
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_infraspecific_epithet,
|
1451
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_author,
|
1452
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_no_author,
|
1453
|
"taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_taxon_name_with_author,
|
1454
|
CASE
|
1455
|
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")
|
1456
|
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")
|
1457
|
ELSE (("taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_genus || ' '::text) || "taxon_scrub.scrubbed_unique_taxon_name.*".scrubbed_specific_epithet)
|
1458
|
END AS scrubbed_morphospecies_binomial
|
1459
|
FROM ("ValidMatchedTaxon"
|
1460
|
LEFT JOIN "taxon_scrub.scrubbed_unique_taxon_name.*" USING (scrubbed_unique_taxon_name));
|
1461
|
|
1462
|
|
1463
|
--
|
1464
|
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
|
1465
|
--
|
1466
|
|
1467
|
COMMENT ON VIEW taxon_scrub IS '
|
1468
|
to modify:
|
1469
|
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
|
1470
|
SELECT __
|
1471
|
$$);
|
1472
|
';
|
1473
|
|
1474
|
|
1475
|
--
|
1476
|
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1477
|
--
|
1478
|
|
1479
|
ALTER TABLE ONLY batch_download_settings
|
1480
|
ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
|
1481
|
|
1482
|
|
1483
|
--
|
1484
|
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1485
|
--
|
1486
|
|
1487
|
ALTER TABLE ONLY batch
|
1488
|
ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
|
1489
|
|
1490
|
|
1491
|
--
|
1492
|
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1493
|
--
|
1494
|
|
1495
|
ALTER TABLE ONLY batch
|
1496
|
ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
|
1497
|
|
1498
|
|
1499
|
--
|
1500
|
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1501
|
--
|
1502
|
|
1503
|
ALTER TABLE ONLY client_version
|
1504
|
ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
|
1505
|
|
1506
|
|
1507
|
--
|
1508
|
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1509
|
--
|
1510
|
|
1511
|
ALTER TABLE ONLY taxon_match
|
1512
|
ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
|
1513
|
|
1514
|
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
|
1515
|
|
1516
|
|
1517
|
--
|
1518
|
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1519
|
--
|
1520
|
|
1521
|
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
|
1522
|
|
1523
|
|
1524
|
--
|
1525
|
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1526
|
--
|
1527
|
|
1528
|
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
|
1529
|
|
1530
|
|
1531
|
--
|
1532
|
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1533
|
--
|
1534
|
|
1535
|
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
|
1536
|
|
1537
|
|
1538
|
--
|
1539
|
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1540
|
--
|
1541
|
|
1542
|
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
|
1543
|
|
1544
|
|
1545
|
--
|
1546
|
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1547
|
--
|
1548
|
|
1549
|
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
|
1550
|
|
1551
|
|
1552
|
--
|
1553
|
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
|
1554
|
--
|
1555
|
|
1556
|
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
|
1557
|
|
1558
|
|
1559
|
--
|
1560
|
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1561
|
--
|
1562
|
|
1563
|
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
|
1564
|
|
1565
|
|
1566
|
--
|
1567
|
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
|
1568
|
--
|
1569
|
|
1570
|
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
|
1571
|
|
1572
|
|
1573
|
--
|
1574
|
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1575
|
--
|
1576
|
|
1577
|
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
|
1578
|
|
1579
|
|
1580
|
--
|
1581
|
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
|
1582
|
--
|
1583
|
|
1584
|
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();
|
1585
|
|
1586
|
|
1587
|
--
|
1588
|
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1589
|
--
|
1590
|
|
1591
|
ALTER TABLE ONLY batch
|
1592
|
ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1593
|
|
1594
|
|
1595
|
--
|
1596
|
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1597
|
--
|
1598
|
|
1599
|
ALTER TABLE ONLY batch_download_settings
|
1600
|
ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1601
|
|
1602
|
|
1603
|
--
|
1604
|
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1605
|
--
|
1606
|
|
1607
|
ALTER TABLE ONLY taxon_match
|
1608
|
ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1609
|
|
1610
|
|
1611
|
--
|
1612
|
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
|
1613
|
--
|
1614
|
|
1615
|
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
|
1616
|
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
|
1617
|
GRANT ALL ON SCHEMA "TNRS" TO bien;
|
1618
|
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
|
1619
|
|
1620
|
|
1621
|
--
|
1622
|
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
|
1623
|
--
|
1624
|
|
1625
|
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
|
1626
|
REVOKE ALL ON TABLE taxon_match FROM bien;
|
1627
|
GRANT ALL ON TABLE taxon_match TO bien;
|
1628
|
GRANT SELECT ON TABLE taxon_match TO bien_read;
|
1629
|
|
1630
|
|
1631
|
--
|
1632
|
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
|
1633
|
--
|
1634
|
|
1635
|
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
|
1636
|
REVOKE ALL ON TABLE taxon_best_match FROM bien;
|
1637
|
GRANT ALL ON TABLE taxon_best_match TO bien;
|
1638
|
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
|
1639
|
|
1640
|
|
1641
|
--
|
1642
|
-- Name: MatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
|
1643
|
--
|
1644
|
|
1645
|
REVOKE ALL ON TABLE "MatchedTaxon" FROM PUBLIC;
|
1646
|
REVOKE ALL ON TABLE "MatchedTaxon" FROM bien;
|
1647
|
GRANT ALL ON TABLE "MatchedTaxon" TO bien;
|
1648
|
GRANT SELECT ON TABLE "MatchedTaxon" TO bien_read;
|
1649
|
|
1650
|
|
1651
|
--
|
1652
|
-- Name: ValidMatchedTaxon; Type: ACL; Schema: TNRS; Owner: -
|
1653
|
--
|
1654
|
|
1655
|
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM PUBLIC;
|
1656
|
REVOKE ALL ON TABLE "ValidMatchedTaxon" FROM bien;
|
1657
|
GRANT ALL ON TABLE "ValidMatchedTaxon" TO bien;
|
1658
|
GRANT SELECT ON TABLE "ValidMatchedTaxon" TO bien_read;
|
1659
|
|
1660
|
|
1661
|
--
|
1662
|
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
|
1663
|
--
|
1664
|
|
1665
|
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
|
1666
|
REVOKE ALL ON TABLE taxon_match_input FROM bien;
|
1667
|
GRANT ALL ON TABLE taxon_match_input TO bien;
|
1668
|
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
|
1669
|
|
1670
|
|
1671
|
--
|
1672
|
-- Name: taxon_scrub.scrubbed_unique_taxon_name.*; Type: ACL; Schema: TNRS; Owner: -
|
1673
|
--
|
1674
|
|
1675
|
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM PUBLIC;
|
1676
|
REVOKE ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" FROM bien;
|
1677
|
GRANT ALL ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien;
|
1678
|
GRANT SELECT ON TABLE "taxon_scrub.scrubbed_unique_taxon_name.*" TO bien_read;
|
1679
|
|
1680
|
|
1681
|
--
|
1682
|
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
|
1683
|
--
|
1684
|
|
1685
|
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
|
1686
|
REVOKE ALL ON TABLE taxon_scrub FROM bien;
|
1687
|
GRANT ALL ON TABLE taxon_scrub TO bien;
|
1688
|
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
|
1689
|
|
1690
|
|
1691
|
--
|
1692
|
-- PostgreSQL database dump complete
|
1693
|
--
|
1694
|
|