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: remove_prefix(text, text, boolean, boolean); Type: FUNCTION; Schema: TNRS; Owner: -
|
97
|
--
|
98
|
|
99
|
CREATE FUNCTION remove_prefix(prefix text, str text, require boolean DEFAULT true, case_sensitive boolean DEFAULT true) RETURNS text
|
100
|
LANGUAGE sql IMMUTABLE
|
101
|
AS $$
|
102
|
SELECT util.remove_prefix(prefix, str, require, case_sensitive)
|
103
|
$$;
|
104
|
|
105
|
|
106
|
--
|
107
|
-- Name: FUNCTION remove_prefix(prefix text, str text, require boolean, case_sensitive boolean); Type: COMMENT; Schema: TNRS; Owner: -
|
108
|
--
|
109
|
|
110
|
COMMENT ON FUNCTION remove_prefix(prefix text, str text, require boolean, case_sensitive boolean) IS '
|
111
|
wrapper that prevents views from getting dropped when the util schema is reinstalled
|
112
|
';
|
113
|
|
114
|
|
115
|
--
|
116
|
-- Name: taxon_match__batch_begin(); Type: FUNCTION; Schema: TNRS; Owner: -
|
117
|
--
|
118
|
|
119
|
CREATE FUNCTION taxon_match__batch_begin() RETURNS trigger
|
120
|
LANGUAGE plpgsql
|
121
|
AS $$
|
122
|
BEGIN
|
123
|
PERFORM util.seq__reset('pg_temp.taxon_match__match_num__seq', 0);
|
124
|
RETURN NULL;
|
125
|
END;
|
126
|
$$;
|
127
|
|
128
|
|
129
|
--
|
130
|
-- Name: taxon_match__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
|
131
|
--
|
132
|
|
133
|
CREATE FUNCTION taxon_match__fill() RETURNS trigger
|
134
|
LANGUAGE plpgsql
|
135
|
AS $$
|
136
|
BEGIN
|
137
|
DECLARE
|
138
|
"Specific_epithet_is_plant" boolean :=
|
139
|
(CASE
|
140
|
WHEN new."*Infraspecific_epithet_matched" IS NOT NULL
|
141
|
OR new."*Infraspecific_epithet_2_matched" IS NOT NULL
|
142
|
OR new."*Specific_epithet_score" >= 0.9 -- fuzzy match
|
143
|
THEN true
|
144
|
ELSE NULL -- ambiguous
|
145
|
END);
|
146
|
never_homonym boolean = COALESCE(new."*Author_score" >= 0.6, false);
|
147
|
-- author disambiguates
|
148
|
family_is_homonym boolean = NOT never_homonym
|
149
|
AND "TNRS".family_is_homonym(new."*Family_matched");
|
150
|
genus_is_homonym boolean = NOT never_homonym
|
151
|
AND "TNRS".genus_is_homonym(new."*Genus_matched");
|
152
|
BEGIN
|
153
|
/* exclude homonyms because these are not valid matches (TNRS provides a
|
154
|
name, but the name is not meaningful because it is not unambiguous) */
|
155
|
new.is_valid_match = new."*Taxonomic_status" != 'Invalid'
|
156
|
AND COALESCE(CASE
|
157
|
WHEN new."*Family_score" = 1 AND NOT family_is_homonym -- exact match
|
158
|
THEN true
|
159
|
ELSE -- consider genus
|
160
|
(CASE
|
161
|
WHEN new."*Genus_score" = 1 -- exact match
|
162
|
THEN
|
163
|
(CASE
|
164
|
WHEN NOT genus_is_homonym THEN true
|
165
|
ELSE "Specific_epithet_is_plant"
|
166
|
END)
|
167
|
WHEN new."*Genus_score" >= 0.85 -- fuzzy match
|
168
|
THEN "Specific_epithet_is_plant"
|
169
|
ELSE NULL -- ambiguous
|
170
|
END)
|
171
|
END, false);
|
172
|
END;
|
173
|
|
174
|
RETURN new;
|
175
|
END;
|
176
|
$$;
|
177
|
|
178
|
|
179
|
--
|
180
|
-- Name: FUNCTION taxon_match__fill(); Type: COMMENT; Schema: TNRS; Owner: -
|
181
|
--
|
182
|
|
183
|
COMMENT ON FUNCTION taxon_match__fill() IS '
|
184
|
IMPORTANT: when changing this function, you must regenerate the derived cols:
|
185
|
UPDATE "TNRS".taxon_match SET "Name_submitted" = "Name_submitted"
|
186
|
runtime: 30 min ("5564082 rows affected, 1918900 ms execution time")
|
187
|
VACUUM ANALYZE "TNRS".taxon_match -- to remove previous rows
|
188
|
runtime: 1.5 min ("92633 ms")
|
189
|
';
|
190
|
|
191
|
|
192
|
--
|
193
|
-- Name: taxon_match__fill_derived(); Type: FUNCTION; Schema: TNRS; Owner: -
|
194
|
--
|
195
|
|
196
|
CREATE FUNCTION taxon_match__fill_derived() RETURNS trigger
|
197
|
LANGUAGE plpgsql
|
198
|
AS $$
|
199
|
BEGIN
|
200
|
-- clear derived cols so old values won't be used in calculations
|
201
|
new."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" = NULL;
|
202
|
new."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" = NULL;
|
203
|
new."matched~Name[_no_author]___@TNRS__@vegpath.org" = NULL;
|
204
|
new."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" = NULL;
|
205
|
new.matched_has_accepted = NULL;
|
206
|
new."Accepted_family__@TNRS__@vegpath.org" = NULL;
|
207
|
new."Accepted_species[_binomial]__@TNRS__@vegpath.org" = NULL;
|
208
|
new."__accepted_{genus,specific_epithet,infra_{rank,epithet}}" = NULL;
|
209
|
new."[accepted_]genus__@DwC__@vegpath.org" = NULL;
|
210
|
new."[accepted_]specificEpithet__@DwC__@vegpath.org" = NULL;
|
211
|
new."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" = NULL;
|
212
|
new."__accepted_infraspecific_{rank,epithet}" = NULL;
|
213
|
new."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = NULL;
|
214
|
new."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" = NULL;
|
215
|
new."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" = NULL;
|
216
|
new."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" = NULL;
|
217
|
new."[scrubbed_]taxonRank__@DwC__@vegpath.org" = NULL;
|
218
|
new."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" = NULL;
|
219
|
new."[scrubbed_]genus__@DwC__@vegpath.org" = NULL;
|
220
|
new."[scrubbed_]specificEpithet__@DwC__@vegpath.org" = NULL;
|
221
|
new."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" = NULL;
|
222
|
new."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" = NULL;
|
223
|
new."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = NULL;
|
224
|
new."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" = NULL;
|
225
|
new."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" = NULL;
|
226
|
new."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" = NULL;
|
227
|
new."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" = NULL;
|
228
|
|
229
|
-- populate derived cols
|
230
|
new."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" = (SELECT "*Unmatched_terms" FROM (SELECT new.*) new);
|
231
|
new."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT ("*Genus_matched" || ' '::text) || "*Specific_epithet_matched" FROM (SELECT new.*) new);
|
232
|
new."matched~Name[_no_author]___@TNRS__@vegpath.org" = (SELECT NULLIF("*Name_matched", 'No suitable matches found.'::text) FROM (SELECT new.*) new);
|
233
|
new."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT "matched~Name[_no_author]___@TNRS__@vegpath.org" || COALESCE((' '::text || "*Name_matched_author"), ''::text) FROM (SELECT new.*) new);
|
234
|
new.matched_has_accepted = (SELECT "*Accepted_name" IS NOT NULL FROM (SELECT new.*) new);
|
235
|
new."Accepted_family__@TNRS__@vegpath.org" = (SELECT COALESCE("*Accepted_name_family",
|
236
|
CASE
|
237
|
WHEN ("*Accepted_name_rank" = 'family'::text) THEN "*Accepted_name"
|
238
|
ELSE NULL::text
|
239
|
END) FROM (SELECT new.*) new);
|
240
|
new."Accepted_species[_binomial]__@TNRS__@vegpath.org" = (SELECT rtrim("*Accepted_name_species", ' '::text) FROM (SELECT new.*) new);
|
241
|
new."__accepted_{genus,specific_epithet,infra_{rank,epithet}}" = (SELECT regexp_split_to_array("*Accepted_name", ' '::text) FROM (SELECT new.*) new);
|
242
|
new."[accepted_]genus__@DwC__@vegpath.org" = (SELECT "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[1] FROM (SELECT new.*) new);
|
243
|
new."[accepted_]specificEpithet__@DwC__@vegpath.org" = (SELECT "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[2] FROM (SELECT new.*) new);
|
244
|
new."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" = (SELECT CASE
|
245
|
WHEN ("*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, "Accepted_family__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
246
|
WHEN ("*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, "[accepted_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
247
|
ELSE "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
248
|
END FROM (SELECT new.*) new);
|
249
|
new."__accepted_infraspecific_{rank,epithet}" = (SELECT NULLIF("__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[3:4], '{}'::text[]) FROM (SELECT new.*) new);
|
250
|
new."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT "__accepted_infraspecific_{rank,epithet}"[1] FROM (SELECT new.*) new);
|
251
|
new."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT "__accepted_infraspecific_{rank,epithet}"[2] FROM (SELECT new.*) new);
|
252
|
new."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT "*Accepted_name" || COALESCE((' '::text || "*Accepted_name_author"), ''::text) FROM (SELECT new.*) new);
|
253
|
new."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" = (SELECT "TNRS".map_taxonomic_status("*Taxonomic_status", "*Accepted_name") FROM (SELECT new.*) new);
|
254
|
new."[scrubbed_]taxonRank__@DwC__@vegpath.org" = (SELECT CASE
|
255
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
256
|
ELSE "*Name_matched_rank"
|
257
|
END FROM (SELECT new.*) new);
|
258
|
new."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT CASE
|
259
|
WHEN matched_has_accepted THEN "Accepted_family__@TNRS__@vegpath.org"
|
260
|
ELSE "*Name_matched_accepted_family"
|
261
|
END FROM (SELECT new.*) new);
|
262
|
new."[scrubbed_]genus__@DwC__@vegpath.org" = (SELECT CASE
|
263
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
264
|
ELSE "*Genus_matched"
|
265
|
END FROM (SELECT new.*) new);
|
266
|
new."[scrubbed_]specificEpithet__@DwC__@vegpath.org" = (SELECT CASE
|
267
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
268
|
ELSE "*Specific_epithet_matched"
|
269
|
END FROM (SELECT new.*) new);
|
270
|
new."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT CASE
|
271
|
WHEN matched_has_accepted THEN "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
272
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
273
|
END FROM (SELECT new.*) new);
|
274
|
new."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" = (SELECT CASE
|
275
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = 'family'::text) THEN concat_ws(' '::text, "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
276
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = 'genus'::text) THEN concat_ws(' '::text, "[scrubbed_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
277
|
ELSE "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"
|
278
|
END FROM (SELECT new.*) new);
|
279
|
new."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" = (SELECT CASE
|
280
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
281
|
ELSE "*Infraspecific_rank"
|
282
|
END FROM (SELECT new.*) new);
|
283
|
new."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" = (SELECT CASE
|
284
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
285
|
ELSE "*Infraspecific_epithet_matched"
|
286
|
END FROM (SELECT new.*) new);
|
287
|
new."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT CASE
|
288
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
289
|
ELSE "matched~Name[_no_author]___@TNRS__@vegpath.org"
|
290
|
END FROM (SELECT new.*) new);
|
291
|
new."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" = (SELECT CASE
|
292
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
293
|
ELSE "*Name_matched_author"
|
294
|
END FROM (SELECT new.*) new);
|
295
|
new."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" = (SELECT CASE
|
296
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
297
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
298
|
END FROM (SELECT new.*) new);
|
299
|
|
300
|
RETURN new;
|
301
|
END;
|
302
|
$$;
|
303
|
|
304
|
|
305
|
--
|
306
|
-- Name: FUNCTION taxon_match__fill_derived(); Type: COMMENT; Schema: TNRS; Owner: -
|
307
|
--
|
308
|
|
309
|
COMMENT ON FUNCTION taxon_match__fill_derived() IS '
|
310
|
autogenerated, do not edit
|
311
|
|
312
|
to regenerate:
|
313
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
314
|
';
|
315
|
|
316
|
|
317
|
--
|
318
|
-- Name: taxon_match__match_num__fill(); Type: FUNCTION; Schema: TNRS; Owner: -
|
319
|
--
|
320
|
|
321
|
CREATE FUNCTION taxon_match__match_num__fill() RETURNS trigger
|
322
|
LANGUAGE plpgsql
|
323
|
AS $$
|
324
|
BEGIN
|
325
|
IF new.match_num IS NULL THEN
|
326
|
new.match_num = "TNRS".taxon_match__match_num__next();
|
327
|
END IF;
|
328
|
RETURN new;
|
329
|
END;
|
330
|
$$;
|
331
|
|
332
|
|
333
|
--
|
334
|
-- Name: taxon_match__match_num__next(); Type: FUNCTION; Schema: TNRS; Owner: -
|
335
|
--
|
336
|
|
337
|
CREATE FUNCTION taxon_match__match_num__next() RETURNS bigint
|
338
|
LANGUAGE sql
|
339
|
AS $$
|
340
|
SELECT nextval('pg_temp.taxon_match__match_num__seq');
|
341
|
$$;
|
342
|
|
343
|
|
344
|
--
|
345
|
-- Name: taxon_match_input__copy_to__insert(); Type: FUNCTION; Schema: TNRS; Owner: -
|
346
|
--
|
347
|
|
348
|
CREATE FUNCTION taxon_match_input__copy_to__insert() RETURNS trigger
|
349
|
LANGUAGE plpgsql
|
350
|
AS $$
|
351
|
BEGIN
|
352
|
INSERT INTO "TNRS".taxon_match_input SELECT new.*;
|
353
|
RETURN NULL;
|
354
|
END;
|
355
|
$$;
|
356
|
|
357
|
|
358
|
--
|
359
|
-- Name: taxon_name_is_safe(text); Type: FUNCTION; Schema: TNRS; Owner: -
|
360
|
--
|
361
|
|
362
|
CREATE FUNCTION taxon_name_is_safe(taxon_name text) RETURNS boolean
|
363
|
LANGUAGE sql IMMUTABLE
|
364
|
AS $_$
|
365
|
SELECT NOT ($1 = ANY("TNRS".unsafe_taxon_names()))
|
366
|
$_$;
|
367
|
|
368
|
|
369
|
--
|
370
|
-- Name: unsafe_taxon_names(); Type: FUNCTION; Schema: TNRS; Owner: -
|
371
|
--
|
372
|
|
373
|
CREATE FUNCTION unsafe_taxon_names() RETURNS text[]
|
374
|
LANGUAGE sql IMMUTABLE
|
375
|
AS $$
|
376
|
SELECT ARRAY[
|
377
|
]::text[]
|
378
|
$$;
|
379
|
|
380
|
|
381
|
SET default_tablespace = '';
|
382
|
|
383
|
SET default_with_oids = false;
|
384
|
|
385
|
--
|
386
|
-- Name: batch; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
387
|
--
|
388
|
|
389
|
CREATE TABLE batch (
|
390
|
id text NOT NULL,
|
391
|
id_by_time text,
|
392
|
time_submitted timestamp with time zone DEFAULT now(),
|
393
|
client_version text
|
394
|
);
|
395
|
|
396
|
|
397
|
--
|
398
|
-- Name: batch_download_settings; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
399
|
--
|
400
|
|
401
|
CREATE TABLE batch_download_settings (
|
402
|
id text NOT NULL,
|
403
|
"E-mail" text,
|
404
|
"Id" text,
|
405
|
"Job type" text,
|
406
|
"Contains Id" boolean,
|
407
|
"Start time" text,
|
408
|
"Finish time" text,
|
409
|
"TNRS version" text,
|
410
|
"Sources selected" text,
|
411
|
"Match threshold" double precision,
|
412
|
"Classification" text,
|
413
|
"Allow partial matches?" boolean,
|
414
|
"Sort by source" boolean,
|
415
|
"Constrain by higher taxonomy" boolean
|
416
|
);
|
417
|
|
418
|
|
419
|
--
|
420
|
-- Name: TABLE batch_download_settings; Type: COMMENT; Schema: TNRS; Owner: -
|
421
|
--
|
422
|
|
423
|
COMMENT ON TABLE batch_download_settings IS '
|
424
|
stores data from http://tnrs.iplantcollaborative.org/TNRSapp.html > Submit List > results section > Download settings > settings.txt
|
425
|
';
|
426
|
|
427
|
|
428
|
--
|
429
|
-- Name: client_version; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
430
|
--
|
431
|
|
432
|
CREATE TABLE client_version (
|
433
|
id text NOT NULL,
|
434
|
global_rev integer NOT NULL,
|
435
|
"/lib/tnrs.py rev" integer,
|
436
|
"/bin/tnrs_db rev" integer
|
437
|
);
|
438
|
|
439
|
|
440
|
--
|
441
|
-- Name: TABLE client_version; Type: COMMENT; Schema: TNRS; Owner: -
|
442
|
--
|
443
|
|
444
|
COMMENT ON TABLE client_version IS '
|
445
|
contains svn revisions
|
446
|
';
|
447
|
|
448
|
|
449
|
--
|
450
|
-- Name: COLUMN client_version.global_rev; Type: COMMENT; Schema: TNRS; Owner: -
|
451
|
--
|
452
|
|
453
|
COMMENT ON COLUMN client_version.global_rev IS '
|
454
|
from `svn info .` > Last Changed Rev
|
455
|
';
|
456
|
|
457
|
|
458
|
--
|
459
|
-- Name: COLUMN client_version."/lib/tnrs.py rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
460
|
--
|
461
|
|
462
|
COMMENT ON COLUMN client_version."/lib/tnrs.py rev" IS '
|
463
|
from `svn info lib/tnrs.py` > Last Changed Rev
|
464
|
';
|
465
|
|
466
|
|
467
|
--
|
468
|
-- Name: COLUMN client_version."/bin/tnrs_db rev"; Type: COMMENT; Schema: TNRS; Owner: -
|
469
|
--
|
470
|
|
471
|
COMMENT ON COLUMN client_version."/bin/tnrs_db rev" IS '
|
472
|
from `svn info bin/tnrs_db` > Last Changed Rev
|
473
|
';
|
474
|
|
475
|
|
476
|
--
|
477
|
-- Name: taxon_match; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
478
|
--
|
479
|
|
480
|
CREATE TABLE taxon_match (
|
481
|
batch text DEFAULT now() NOT NULL,
|
482
|
match_num integer NOT NULL,
|
483
|
"*Name_number" integer NOT NULL,
|
484
|
"*Name_submitted" text NOT NULL,
|
485
|
"*Overall_score" double precision,
|
486
|
"*Name_matched" text,
|
487
|
"*Name_matched_rank" text,
|
488
|
"*Name_score" double precision,
|
489
|
"*Name_matched_author" text,
|
490
|
"*Name_matched_url" text,
|
491
|
"*Author_matched" text,
|
492
|
"*Author_score" double precision,
|
493
|
"*Family_matched" text,
|
494
|
"*Family_score" double precision,
|
495
|
"*Name_matched_accepted_family" text,
|
496
|
"*Genus_matched" text,
|
497
|
"*Genus_score" double precision,
|
498
|
"*Specific_epithet_matched" text,
|
499
|
"*Specific_epithet_score" double precision,
|
500
|
"*Infraspecific_rank" text,
|
501
|
"*Infraspecific_epithet_matched" text,
|
502
|
"*Infraspecific_epithet_score" double precision,
|
503
|
"*Infraspecific_rank_2" text,
|
504
|
"*Infraspecific_epithet_2_matched" text,
|
505
|
"*Infraspecific_epithet_2_score" double precision,
|
506
|
"*Annotations" text,
|
507
|
"*Unmatched_terms" text,
|
508
|
"*Taxonomic_status" text,
|
509
|
"*Accepted_name" text,
|
510
|
"*Accepted_name_author" text,
|
511
|
"*Accepted_name_rank" text,
|
512
|
"*Accepted_name_url" text,
|
513
|
"*Accepted_name_species" text,
|
514
|
"*Accepted_name_family" text,
|
515
|
"*Selected" text,
|
516
|
"*Source" text,
|
517
|
"*Warnings" text,
|
518
|
"*Accepted_name_lsid" text,
|
519
|
is_valid_match boolean NOT NULL,
|
520
|
"[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" text,
|
521
|
"[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
522
|
"matched~Name[_no_author]___@TNRS__@vegpath.org" text,
|
523
|
"[matched_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
524
|
matched_has_accepted boolean,
|
525
|
"Accepted_family__@TNRS__@vegpath.org" text,
|
526
|
"Accepted_species[_binomial]__@TNRS__@vegpath.org" text,
|
527
|
"__accepted_{genus,specific_epithet,infra_{rank,epithet}}" text[],
|
528
|
"[accepted_]genus__@DwC__@vegpath.org" text,
|
529
|
"[accepted_]specificEpithet__@DwC__@vegpath.org" text,
|
530
|
"[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" text,
|
531
|
"__accepted_infraspecific_{rank,epithet}" text[],
|
532
|
"[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
|
533
|
"[accepted_]infraspecificEpithet__@DwC__@vegpath.org" text,
|
534
|
"[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
535
|
"[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" text,
|
536
|
"[scrubbed_]taxonRank__@DwC__@vegpath.org" text,
|
537
|
"[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
538
|
"[scrubbed_]genus__@DwC__@vegpath.org" text,
|
539
|
"[scrubbed_]specificEpithet__@DwC__@vegpath.org" text,
|
540
|
"[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
541
|
"[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" text,
|
542
|
"[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" text,
|
543
|
"[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" text,
|
544
|
"[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
545
|
"[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" text,
|
546
|
"[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" text,
|
547
|
CONSTRAINT "Accepted_family__@TNRS__@vegpath.org" CHECK ((NOT ("Accepted_family__@TNRS__@vegpath.org" IS DISTINCT FROM COALESCE("*Accepted_name_family",
|
548
|
CASE
|
549
|
WHEN ("*Accepted_name_rank" = 'family'::text) THEN "*Accepted_name"
|
550
|
ELSE NULL::text
|
551
|
END)))),
|
552
|
CONSTRAINT "Accepted_species[_binomial]__@TNRS__@vegpath.org" CHECK ((NOT ("Accepted_species[_binomial]__@TNRS__@vegpath.org" IS DISTINCT FROM rtrim("*Accepted_name_species", ' '::text)))),
|
553
|
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]))),
|
554
|
CONSTRAINT "[accepted_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]genus__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[1]))),
|
555
|
CONSTRAINT "[accepted_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_infraspecific_{rank,epithet}"[2]))),
|
556
|
CONSTRAINT "[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" CHECK ((NOT ("[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" IS DISTINCT FROM
|
557
|
CASE
|
558
|
WHEN ("*Accepted_name_rank" = 'family'::text) THEN concat_ws(' '::text, "Accepted_family__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
559
|
WHEN ("*Accepted_name_rank" = 'genus'::text) THEN concat_ws(' '::text, "[accepted_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
560
|
ELSE "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
561
|
END))),
|
562
|
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))))),
|
563
|
CONSTRAINT "[accepted_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[accepted_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[2]))),
|
564
|
CONSTRAINT "[matched_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM ("matched~Name[_no_author]___@TNRS__@vegpath.org" || COALESCE((' '::text || "*Name_matched_author"), ''::text))))),
|
565
|
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")))),
|
566
|
CONSTRAINT "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" CHECK ((NOT ("[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" IS DISTINCT FROM "*Unmatched_terms"))),
|
567
|
CONSTRAINT "[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS DISTINCT FROM
|
568
|
CASE
|
569
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
570
|
ELSE "*Infraspecific_rank"
|
571
|
END))),
|
572
|
CONSTRAINT "[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
573
|
CASE
|
574
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
575
|
ELSE "*Name_matched_author"
|
576
|
END))),
|
577
|
CONSTRAINT "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
578
|
CASE
|
579
|
WHEN matched_has_accepted THEN "Accepted_family__@TNRS__@vegpath.org"
|
580
|
ELSE "*Name_matched_accepted_family"
|
581
|
END))),
|
582
|
CONSTRAINT "[scrubbed_]genus__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]genus__@DwC__@vegpath.org" IS DISTINCT FROM
|
583
|
CASE
|
584
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
585
|
ELSE "*Genus_matched"
|
586
|
END))),
|
587
|
CONSTRAINT "[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
|
588
|
CASE
|
589
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
590
|
ELSE "*Infraspecific_epithet_matched"
|
591
|
END))),
|
592
|
CONSTRAINT "[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" CHECK ((NOT ("[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" IS DISTINCT FROM
|
593
|
CASE
|
594
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = 'family'::text) THEN concat_ws(' '::text, "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
595
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = 'genus'::text) THEN concat_ws(' '::text, "[scrubbed_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
596
|
ELSE "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"
|
597
|
END))),
|
598
|
CONSTRAINT "[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
599
|
CASE
|
600
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
601
|
ELSE "matched~Name[_no_author]___@TNRS__@vegpath.org"
|
602
|
END))),
|
603
|
CONSTRAINT "[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS DISTINCT FROM
|
604
|
CASE
|
605
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
606
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
607
|
END))),
|
608
|
CONSTRAINT "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" CHECK ((NOT ("[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS DISTINCT FROM
|
609
|
CASE
|
610
|
WHEN matched_has_accepted THEN "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
611
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
612
|
END))),
|
613
|
CONSTRAINT "[scrubbed_]specificEpithet__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS DISTINCT FROM
|
614
|
CASE
|
615
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
616
|
ELSE "*Specific_epithet_matched"
|
617
|
END))),
|
618
|
CONSTRAINT "[scrubbed_]taxonRank__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]taxonRank__@DwC__@vegpath.org" IS DISTINCT FROM
|
619
|
CASE
|
620
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
621
|
ELSE "*Name_matched_rank"
|
622
|
END))),
|
623
|
CONSTRAINT "[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" CHECK ((NOT ("[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" IS DISTINCT FROM map_taxonomic_status("*Taxonomic_status", "*Accepted_name")))),
|
624
|
CONSTRAINT "__accepted_infraspecific_{rank,epithet}" CHECK ((NOT ("__accepted_infraspecific_{rank,epithet}" IS DISTINCT FROM NULLIF("__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[3:4], '{}'::text[])))),
|
625
|
CONSTRAINT "__accepted_{genus,specific_epithet,infra_{rank,epithet}}" CHECK ((NOT ("__accepted_{genus,specific_epithet,infra_{rank,epithet}}" IS DISTINCT FROM regexp_split_to_array("*Accepted_name", ' '::text)))),
|
626
|
CONSTRAINT matched_has_accepted CHECK ((NOT (matched_has_accepted IS DISTINCT FROM ("*Accepted_name" IS NOT NULL)))),
|
627
|
CONSTRAINT "matched~Name[_no_author]___@TNRS__@vegpath.org" CHECK ((NOT ("matched~Name[_no_author]___@TNRS__@vegpath.org" IS DISTINCT FROM NULLIF("*Name_matched", 'No suitable matches found.'::text))))
|
628
|
);
|
629
|
|
630
|
|
631
|
--
|
632
|
-- Name: TABLE taxon_match; Type: COMMENT; Schema: TNRS; Owner: -
|
633
|
--
|
634
|
|
635
|
COMMENT ON TABLE taxon_match IS '
|
636
|
whenever columns are renamed:
|
637
|
SELECT util.derived_cols_update(''"TNRS".taxon_match'');
|
638
|
|
639
|
to port derived column changes to vegbiendev:
|
640
|
SELECT util.derived_cols_export(''"TNRS".taxon_match'');
|
641
|
# run the returned SQL on vegbiendev
|
642
|
-- runtime: 6 h, 2.6 ms/row ("22030570 ms"; "rows=8353235")
|
643
|
SELECT util.recreate_view(''"TNRS".taxon_best_match'');
|
644
|
|
645
|
to add a new derived column:
|
646
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''col''), $$
|
647
|
expr
|
648
|
$$));
|
649
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match'');
|
650
|
SELECT util.recreate_view(''"TNRS".taxon_best_match'');
|
651
|
$ make schemas/remake
|
652
|
|
653
|
to remove a derived column:
|
654
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''col''));
|
655
|
$ make schemas/remake
|
656
|
|
657
|
to remove a non-derived column:
|
658
|
SELECT util.drop_column((''"TNRS".taxon_match'', ''col''));
|
659
|
$ make schemas/remake
|
660
|
|
661
|
to move a derived column to the middle or to add a non-derived column:
|
662
|
make the changes in inputs/.TNRS/schema.sql
|
663
|
$ inputs/.TNRS/data.sql.run refresh # re-run TNRS; runtime: 1 min ("1m2.629s")
|
664
|
SELECT util.derived_cols_update(''"TNRS".taxon_match'');
|
665
|
SELECT util.derived_cols_repopulate(''"TNRS".taxon_match'');
|
666
|
SELECT util.recreate_view(''"TNRS".taxon_best_match'');
|
667
|
$ make schemas/remake
|
668
|
|
669
|
to add a constraint: runtime: 3 min ("173620 ms")
|
670
|
';
|
671
|
|
672
|
|
673
|
--
|
674
|
-- Name: COLUMN taxon_match."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
675
|
--
|
676
|
|
677
|
COMMENT ON COLUMN taxon_match."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org" IS '
|
678
|
= "*Unmatched_terms"
|
679
|
|
680
|
derived column
|
681
|
|
682
|
to modify expr:
|
683
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org'')::util.col, $$"*Unmatched_terms"$$)::util.derived_col_def);
|
684
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
685
|
|
686
|
to rename:
|
687
|
# rename column
|
688
|
# rename CHECK constraint
|
689
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
690
|
|
691
|
to drop:
|
692
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org'')::util.col);
|
693
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
694
|
';
|
695
|
|
696
|
|
697
|
--
|
698
|
-- Name: COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
699
|
--
|
700
|
|
701
|
COMMENT ON COLUMN taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
702
|
= ("*Genus_matched" || '' ''::text) || "*Specific_epithet_matched"
|
703
|
|
704
|
derived column
|
705
|
|
706
|
to modify expr:
|
707
|
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);
|
708
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
709
|
|
710
|
to rename:
|
711
|
# rename column
|
712
|
# rename CHECK constraint
|
713
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
714
|
|
715
|
to drop:
|
716
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col);
|
717
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
718
|
';
|
719
|
|
720
|
|
721
|
--
|
722
|
-- Name: COLUMN taxon_match."matched~Name[_no_author]___@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
723
|
--
|
724
|
|
725
|
COMMENT ON COLUMN taxon_match."matched~Name[_no_author]___@TNRS__@vegpath.org" IS '
|
726
|
= NULLIF("*Name_matched", ''No suitable matches found.''::text)
|
727
|
|
728
|
derived column
|
729
|
|
730
|
to modify expr:
|
731
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''matched~Name[_no_author]___@TNRS__@vegpath.org'')::util.col, $$NULLIF("*Name_matched", ''No suitable matches found.''::text)$$)::util.derived_col_def);
|
732
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
733
|
|
734
|
to rename:
|
735
|
# rename column
|
736
|
# rename CHECK constraint
|
737
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
738
|
|
739
|
to drop:
|
740
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''matched~Name[_no_author]___@TNRS__@vegpath.org'')::util.col);
|
741
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
742
|
';
|
743
|
|
744
|
|
745
|
--
|
746
|
-- Name: COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
747
|
--
|
748
|
|
749
|
COMMENT ON COLUMN taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
750
|
= "matched~Name[_no_author]___@TNRS__@vegpath.org" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)
|
751
|
|
752
|
derived column
|
753
|
|
754
|
to modify expr:
|
755
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[matched_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$"matched~Name[_no_author]___@TNRS__@vegpath.org" || COALESCE(('' ''::text || "*Name_matched_author"), ''''::text)$$)::util.derived_col_def);
|
756
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
757
|
|
758
|
to rename:
|
759
|
# rename column
|
760
|
# rename CHECK constraint
|
761
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
762
|
|
763
|
to drop:
|
764
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[matched_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col);
|
765
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
766
|
';
|
767
|
|
768
|
|
769
|
--
|
770
|
-- Name: COLUMN taxon_match.matched_has_accepted; Type: COMMENT; Schema: TNRS; Owner: -
|
771
|
--
|
772
|
|
773
|
COMMENT ON COLUMN taxon_match.matched_has_accepted IS '
|
774
|
= "*Accepted_name" IS NOT NULL
|
775
|
|
776
|
derived column
|
777
|
|
778
|
to modify expr:
|
779
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''matched_has_accepted'')::util.col, $$"*Accepted_name" IS NOT NULL$$)::util.derived_col_def);
|
780
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
781
|
|
782
|
to rename:
|
783
|
# rename column
|
784
|
# rename CHECK constraint
|
785
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
786
|
|
787
|
to drop:
|
788
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''matched_has_accepted'')::util.col);
|
789
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
790
|
';
|
791
|
|
792
|
|
793
|
--
|
794
|
-- Name: COLUMN taxon_match."Accepted_family__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
795
|
--
|
796
|
|
797
|
COMMENT ON COLUMN taxon_match."Accepted_family__@TNRS__@vegpath.org" IS '
|
798
|
= COALESCE("*Accepted_name_family",
|
799
|
CASE
|
800
|
WHEN ("*Accepted_name_rank" = ''family''::text) THEN "*Accepted_name"
|
801
|
ELSE NULL::text
|
802
|
END)
|
803
|
|
804
|
derived column
|
805
|
|
806
|
to modify expr:
|
807
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''Accepted_family__@TNRS__@vegpath.org'')::util.col, $$COALESCE("*Accepted_name_family",
|
808
|
CASE
|
809
|
WHEN ("*Accepted_name_rank" = ''family''::text) THEN "*Accepted_name"
|
810
|
ELSE NULL::text
|
811
|
END)$$)::util.derived_col_def);
|
812
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
813
|
|
814
|
to rename:
|
815
|
# rename column
|
816
|
# rename CHECK constraint
|
817
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
818
|
|
819
|
to drop:
|
820
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''Accepted_family__@TNRS__@vegpath.org'')::util.col);
|
821
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
822
|
';
|
823
|
|
824
|
|
825
|
--
|
826
|
-- Name: COLUMN taxon_match."Accepted_species[_binomial]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
827
|
--
|
828
|
|
829
|
COMMENT ON COLUMN taxon_match."Accepted_species[_binomial]__@TNRS__@vegpath.org" IS '
|
830
|
= rtrim("*Accepted_name_species", '' ''::text)
|
831
|
|
832
|
derived column
|
833
|
|
834
|
to modify expr:
|
835
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''Accepted_species[_binomial]__@TNRS__@vegpath.org'')::util.col, $$rtrim("*Accepted_name_species", '' ''::text)$$)::util.derived_col_def);
|
836
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
837
|
|
838
|
to rename:
|
839
|
# rename column
|
840
|
# rename CHECK constraint
|
841
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
842
|
|
843
|
to drop:
|
844
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''Accepted_species[_binomial]__@TNRS__@vegpath.org'')::util.col);
|
845
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
846
|
';
|
847
|
|
848
|
|
849
|
--
|
850
|
-- Name: COLUMN taxon_match."__accepted_{genus,specific_epithet,infra_{rank,epithet}}"; Type: COMMENT; Schema: TNRS; Owner: -
|
851
|
--
|
852
|
|
853
|
COMMENT ON COLUMN taxon_match."__accepted_{genus,specific_epithet,infra_{rank,epithet}}" IS '
|
854
|
= regexp_split_to_array("*Accepted_name", '' ''::text)
|
855
|
|
856
|
derived column
|
857
|
|
858
|
to modify expr:
|
859
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_{genus,specific_epithet,infra_{rank,epithet}}'')::util.col, $$regexp_split_to_array("*Accepted_name", '' ''::text)$$)::util.derived_col_def);
|
860
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
861
|
|
862
|
to rename:
|
863
|
# rename column
|
864
|
# rename CHECK constraint
|
865
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
866
|
|
867
|
to drop:
|
868
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''__accepted_{genus,specific_epithet,infra_{rank,epithet}}'')::util.col);
|
869
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
870
|
';
|
871
|
|
872
|
|
873
|
--
|
874
|
-- Name: COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
875
|
--
|
876
|
|
877
|
COMMENT ON COLUMN taxon_match."[accepted_]genus__@DwC__@vegpath.org" IS '
|
878
|
= "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[1]
|
879
|
|
880
|
derived column
|
881
|
|
882
|
to modify expr:
|
883
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]genus__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[1]$$)::util.derived_col_def);
|
884
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
885
|
|
886
|
to rename:
|
887
|
# rename column
|
888
|
# rename CHECK constraint
|
889
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
890
|
|
891
|
to drop:
|
892
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]genus__@DwC__@vegpath.org'')::util.col);
|
893
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
894
|
';
|
895
|
|
896
|
|
897
|
--
|
898
|
-- Name: COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
899
|
--
|
900
|
|
901
|
COMMENT ON COLUMN taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org" IS '
|
902
|
= "__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[2]
|
903
|
|
904
|
derived column
|
905
|
|
906
|
to modify expr:
|
907
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[2]$$)::util.derived_col_def);
|
908
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
909
|
|
910
|
to rename:
|
911
|
# rename column
|
912
|
# rename CHECK constraint
|
913
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
914
|
|
915
|
to drop:
|
916
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]specificEpithet__@DwC__@vegpath.org'')::util.col);
|
917
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
918
|
';
|
919
|
|
920
|
|
921
|
--
|
922
|
-- Name: COLUMN taxon_match."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
923
|
--
|
924
|
|
925
|
COMMENT ON COLUMN taxon_match."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" IS '
|
926
|
= CASE
|
927
|
WHEN ("*Accepted_name_rank" = ''family''::text) THEN concat_ws('' ''::text, "Accepted_family__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
928
|
WHEN ("*Accepted_name_rank" = ''genus''::text) THEN concat_ws('' ''::text, "[accepted_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
929
|
ELSE "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
930
|
END
|
931
|
|
932
|
derived column
|
933
|
|
934
|
to modify expr:
|
935
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org'')::util.col, $$CASE
|
936
|
WHEN ("*Accepted_name_rank" = ''family''::text) THEN concat_ws('' ''::text, "Accepted_family__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
937
|
WHEN ("*Accepted_name_rank" = ''genus''::text) THEN concat_ws('' ''::text, "[accepted_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
938
|
ELSE "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
939
|
END$$)::util.derived_col_def);
|
940
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
941
|
|
942
|
to rename:
|
943
|
# rename column
|
944
|
# rename CHECK constraint
|
945
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
946
|
|
947
|
to drop:
|
948
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org'')::util.col);
|
949
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
950
|
';
|
951
|
|
952
|
|
953
|
--
|
954
|
-- Name: COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}"; Type: COMMENT; Schema: TNRS; Owner: -
|
955
|
--
|
956
|
|
957
|
COMMENT ON COLUMN taxon_match."__accepted_infraspecific_{rank,epithet}" IS '
|
958
|
= NULLIF("__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[3:4], ''{}''::text[])
|
959
|
|
960
|
derived column
|
961
|
|
962
|
to modify expr:
|
963
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''__accepted_infraspecific_{rank,epithet}'')::util.col, $$NULLIF("__accepted_{genus,specific_epithet,infra_{rank,epithet}}"[3:4], ''{}''::text[])$$)::util.derived_col_def);
|
964
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
965
|
|
966
|
to rename:
|
967
|
# rename column
|
968
|
# rename CHECK constraint
|
969
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
970
|
|
971
|
to drop:
|
972
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''__accepted_infraspecific_{rank,epithet}'')::util.col);
|
973
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
974
|
';
|
975
|
|
976
|
|
977
|
--
|
978
|
-- Name: COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
979
|
--
|
980
|
|
981
|
COMMENT ON COLUMN taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
|
982
|
= "__accepted_infraspecific_{rank,epithet}"[1]
|
983
|
|
984
|
derived column
|
985
|
|
986
|
to modify expr:
|
987
|
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);
|
988
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
989
|
|
990
|
to rename:
|
991
|
# rename column
|
992
|
# rename CHECK constraint
|
993
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
994
|
|
995
|
to drop:
|
996
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col);
|
997
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
998
|
';
|
999
|
|
1000
|
|
1001
|
--
|
1002
|
-- Name: COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1003
|
--
|
1004
|
|
1005
|
COMMENT ON COLUMN taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org" IS '
|
1006
|
= "__accepted_infraspecific_{rank,epithet}"[2]
|
1007
|
|
1008
|
derived column
|
1009
|
|
1010
|
to modify expr:
|
1011
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[accepted_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$"__accepted_infraspecific_{rank,epithet}"[2]$$)::util.derived_col_def);
|
1012
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1013
|
|
1014
|
to rename:
|
1015
|
# rename column
|
1016
|
# rename CHECK constraint
|
1017
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1018
|
|
1019
|
to drop:
|
1020
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col);
|
1021
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1022
|
';
|
1023
|
|
1024
|
|
1025
|
--
|
1026
|
-- Name: COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1027
|
--
|
1028
|
|
1029
|
COMMENT ON COLUMN taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
1030
|
= "*Accepted_name" || COALESCE(('' ''::text || "*Accepted_name_author"), ''''::text)
|
1031
|
|
1032
|
derived column
|
1033
|
|
1034
|
to modify expr:
|
1035
|
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);
|
1036
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1037
|
|
1038
|
to rename:
|
1039
|
# rename column
|
1040
|
# rename CHECK constraint
|
1041
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1042
|
|
1043
|
to drop:
|
1044
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[accepted_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col);
|
1045
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1046
|
';
|
1047
|
|
1048
|
|
1049
|
--
|
1050
|
-- Name: COLUMN taxon_match."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1051
|
--
|
1052
|
|
1053
|
COMMENT ON COLUMN taxon_match."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org" IS '
|
1054
|
= "TNRS".map_taxonomic_status("*Taxonomic_status", "*Accepted_name")
|
1055
|
|
1056
|
derived column
|
1057
|
|
1058
|
to modify expr:
|
1059
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]taxonomicStatus__@DwC__@vegpath.org'')::util.col, $$"TNRS".map_taxonomic_status("*Taxonomic_status", "*Accepted_name")$$)::util.derived_col_def);
|
1060
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1061
|
|
1062
|
to rename:
|
1063
|
# rename column
|
1064
|
# rename CHECK constraint
|
1065
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1066
|
|
1067
|
to drop:
|
1068
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]taxonomicStatus__@DwC__@vegpath.org'')::util.col);
|
1069
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1070
|
';
|
1071
|
|
1072
|
|
1073
|
--
|
1074
|
-- Name: COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1075
|
--
|
1076
|
|
1077
|
COMMENT ON COLUMN taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org" IS '
|
1078
|
= CASE
|
1079
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
1080
|
ELSE "*Name_matched_rank"
|
1081
|
END
|
1082
|
|
1083
|
derived column
|
1084
|
|
1085
|
to modify expr:
|
1086
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]taxonRank__@DwC__@vegpath.org'')::util.col, $$CASE
|
1087
|
WHEN matched_has_accepted THEN "*Accepted_name_rank"
|
1088
|
ELSE "*Name_matched_rank"
|
1089
|
END$$)::util.derived_col_def);
|
1090
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1091
|
|
1092
|
to rename:
|
1093
|
# rename column
|
1094
|
# rename CHECK constraint
|
1095
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1096
|
|
1097
|
to drop:
|
1098
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]taxonRank__@DwC__@vegpath.org'')::util.col);
|
1099
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1100
|
';
|
1101
|
|
1102
|
|
1103
|
--
|
1104
|
-- Name: COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1105
|
--
|
1106
|
|
1107
|
COMMENT ON COLUMN taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
1108
|
= CASE
|
1109
|
WHEN matched_has_accepted THEN "Accepted_family__@TNRS__@vegpath.org"
|
1110
|
ELSE "*Name_matched_accepted_family"
|
1111
|
END
|
1112
|
|
1113
|
derived column
|
1114
|
|
1115
|
to modify expr:
|
1116
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
|
1117
|
WHEN matched_has_accepted THEN "Accepted_family__@TNRS__@vegpath.org"
|
1118
|
ELSE "*Name_matched_accepted_family"
|
1119
|
END$$)::util.derived_col_def);
|
1120
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1121
|
|
1122
|
to rename:
|
1123
|
# rename column
|
1124
|
# rename CHECK constraint
|
1125
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1126
|
|
1127
|
to drop:
|
1128
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col);
|
1129
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1130
|
';
|
1131
|
|
1132
|
|
1133
|
--
|
1134
|
-- Name: COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1135
|
--
|
1136
|
|
1137
|
COMMENT ON COLUMN taxon_match."[scrubbed_]genus__@DwC__@vegpath.org" IS '
|
1138
|
= CASE
|
1139
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
1140
|
ELSE "*Genus_matched"
|
1141
|
END
|
1142
|
|
1143
|
derived column
|
1144
|
|
1145
|
to modify expr:
|
1146
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]genus__@DwC__@vegpath.org'')::util.col, $$CASE
|
1147
|
WHEN matched_has_accepted THEN "[accepted_]genus__@DwC__@vegpath.org"
|
1148
|
ELSE "*Genus_matched"
|
1149
|
END$$)::util.derived_col_def);
|
1150
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1151
|
|
1152
|
to rename:
|
1153
|
# rename column
|
1154
|
# rename CHECK constraint
|
1155
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1156
|
|
1157
|
to drop:
|
1158
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]genus__@DwC__@vegpath.org'')::util.col);
|
1159
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1160
|
';
|
1161
|
|
1162
|
|
1163
|
--
|
1164
|
-- Name: COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1165
|
--
|
1166
|
|
1167
|
COMMENT ON COLUMN taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org" IS '
|
1168
|
= CASE
|
1169
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
1170
|
ELSE "*Specific_epithet_matched"
|
1171
|
END
|
1172
|
|
1173
|
derived column
|
1174
|
|
1175
|
to modify expr:
|
1176
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]specificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE
|
1177
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
1178
|
ELSE "*Specific_epithet_matched"
|
1179
|
END$$)::util.derived_col_def);
|
1180
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1181
|
|
1182
|
to rename:
|
1183
|
# rename column
|
1184
|
# rename CHECK constraint
|
1185
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1186
|
|
1187
|
to drop:
|
1188
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]specificEpithet__@DwC__@vegpath.org'')::util.col);
|
1189
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1190
|
';
|
1191
|
|
1192
|
|
1193
|
--
|
1194
|
-- Name: COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1195
|
--
|
1196
|
|
1197
|
COMMENT ON COLUMN taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
1198
|
= CASE
|
1199
|
WHEN matched_has_accepted THEN "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
1200
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
1201
|
END
|
1202
|
|
1203
|
derived column
|
1204
|
|
1205
|
to modify expr:
|
1206
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
|
1207
|
WHEN matched_has_accepted THEN "Accepted_species[_binomial]__@TNRS__@vegpath.org"
|
1208
|
ELSE "[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org"
|
1209
|
END$$)::util.derived_col_def);
|
1210
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1211
|
|
1212
|
to rename:
|
1213
|
# rename column
|
1214
|
# rename CHECK constraint
|
1215
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1216
|
|
1217
|
to drop:
|
1218
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col);
|
1219
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1220
|
';
|
1221
|
|
1222
|
|
1223
|
--
|
1224
|
-- Name: COLUMN taxon_match."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1225
|
--
|
1226
|
|
1227
|
COMMENT ON COLUMN taxon_match."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org" IS '
|
1228
|
= CASE
|
1229
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = ''family''::text) THEN concat_ws('' ''::text, "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
1230
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = ''genus''::text) THEN concat_ws('' ''::text, "[scrubbed_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
1231
|
ELSE "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"
|
1232
|
END
|
1233
|
|
1234
|
derived column
|
1235
|
|
1236
|
to modify expr:
|
1237
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org'')::util.col, $$CASE
|
1238
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = ''family''::text) THEN concat_ws('' ''::text, "[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
1239
|
WHEN ("[scrubbed_]taxonRank__@DwC__@vegpath.org" = ''genus''::text) THEN concat_ws('' ''::text, "[scrubbed_]genus__@DwC__@vegpath.org", "[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org")
|
1240
|
ELSE "[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org"
|
1241
|
END$$)::util.derived_col_def);
|
1242
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1243
|
|
1244
|
to rename:
|
1245
|
# rename column
|
1246
|
# rename CHECK constraint
|
1247
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1248
|
|
1249
|
to drop:
|
1250
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org'')::util.col);
|
1251
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1252
|
';
|
1253
|
|
1254
|
|
1255
|
--
|
1256
|
-- Name: COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1257
|
--
|
1258
|
|
1259
|
COMMENT ON COLUMN taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org" IS '
|
1260
|
= CASE
|
1261
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
1262
|
ELSE "*Infraspecific_rank"
|
1263
|
END
|
1264
|
|
1265
|
derived column
|
1266
|
|
1267
|
to modify expr:
|
1268
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col, $$CASE
|
1269
|
WHEN matched_has_accepted THEN "[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org"
|
1270
|
ELSE "*Infraspecific_rank"
|
1271
|
END$$)::util.derived_col_def);
|
1272
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1273
|
|
1274
|
to rename:
|
1275
|
# rename column
|
1276
|
# rename CHECK constraint
|
1277
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1278
|
|
1279
|
to drop:
|
1280
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org'')::util.col);
|
1281
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1282
|
';
|
1283
|
|
1284
|
|
1285
|
--
|
1286
|
-- Name: COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1287
|
--
|
1288
|
|
1289
|
COMMENT ON COLUMN taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org" IS '
|
1290
|
= CASE
|
1291
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
1292
|
ELSE "*Infraspecific_epithet_matched"
|
1293
|
END
|
1294
|
|
1295
|
derived column
|
1296
|
|
1297
|
to modify expr:
|
1298
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col, $$CASE
|
1299
|
WHEN matched_has_accepted THEN "[accepted_]specificEpithet__@DwC__@vegpath.org"
|
1300
|
ELSE "*Infraspecific_epithet_matched"
|
1301
|
END$$)::util.derived_col_def);
|
1302
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1303
|
|
1304
|
to rename:
|
1305
|
# rename column
|
1306
|
# rename CHECK constraint
|
1307
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1308
|
|
1309
|
to drop:
|
1310
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org'')::util.col);
|
1311
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1312
|
';
|
1313
|
|
1314
|
|
1315
|
--
|
1316
|
-- Name: COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1317
|
--
|
1318
|
|
1319
|
COMMENT ON COLUMN taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
1320
|
= CASE
|
1321
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
1322
|
ELSE "matched~Name[_no_author]___@TNRS__@vegpath.org"
|
1323
|
END
|
1324
|
|
1325
|
derived column
|
1326
|
|
1327
|
to modify expr:
|
1328
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
|
1329
|
WHEN matched_has_accepted THEN "*Accepted_name"
|
1330
|
ELSE "matched~Name[_no_author]___@TNRS__@vegpath.org"
|
1331
|
END$$)::util.derived_col_def);
|
1332
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1333
|
|
1334
|
to rename:
|
1335
|
# rename column
|
1336
|
# rename CHECK constraint
|
1337
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1338
|
|
1339
|
to drop:
|
1340
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col);
|
1341
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1342
|
';
|
1343
|
|
1344
|
|
1345
|
--
|
1346
|
-- Name: COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1347
|
--
|
1348
|
|
1349
|
COMMENT ON COLUMN taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org" IS '
|
1350
|
= CASE
|
1351
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
1352
|
ELSE "*Name_matched_author"
|
1353
|
END
|
1354
|
|
1355
|
derived column
|
1356
|
|
1357
|
to modify expr:
|
1358
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col, $$CASE
|
1359
|
WHEN matched_has_accepted THEN "*Accepted_name_author"
|
1360
|
ELSE "*Name_matched_author"
|
1361
|
END$$)::util.derived_col_def);
|
1362
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1363
|
|
1364
|
to rename:
|
1365
|
# rename column
|
1366
|
# rename CHECK constraint
|
1367
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1368
|
|
1369
|
to drop:
|
1370
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org'')::util.col);
|
1371
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1372
|
';
|
1373
|
|
1374
|
|
1375
|
--
|
1376
|
-- Name: COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org"; Type: COMMENT; Schema: TNRS; Owner: -
|
1377
|
--
|
1378
|
|
1379
|
COMMENT ON COLUMN taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org" IS '
|
1380
|
= CASE
|
1381
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1382
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1383
|
END
|
1384
|
|
1385
|
derived column
|
1386
|
|
1387
|
to modify expr:
|
1388
|
SELECT util.derived_col_update(((''"TNRS".taxon_match'', ''[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col, $$CASE
|
1389
|
WHEN matched_has_accepted THEN "[accepted_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1390
|
ELSE "[matched_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1391
|
END$$)::util.derived_col_def);
|
1392
|
SELECT util.derived_cols_populate(''"TNRS".taxon_match''::regclass);
|
1393
|
|
1394
|
to rename:
|
1395
|
# rename column
|
1396
|
# rename CHECK constraint
|
1397
|
SELECT util.derived_cols_update(''"TNRS".taxon_match''::regclass);
|
1398
|
|
1399
|
to drop:
|
1400
|
SELECT util.drop_derived_col((''"TNRS".taxon_match'', ''[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org'')::util.col);
|
1401
|
-- DROP __ CASCADE doesn''t work when there are dependent views
|
1402
|
';
|
1403
|
|
1404
|
|
1405
|
--
|
1406
|
-- Name: taxon_best_match; Type: VIEW; Schema: TNRS; Owner: -
|
1407
|
--
|
1408
|
|
1409
|
CREATE VIEW taxon_best_match AS
|
1410
|
SELECT taxon_match.batch,
|
1411
|
taxon_match.match_num,
|
1412
|
taxon_match."*Name_number",
|
1413
|
taxon_match."*Name_submitted",
|
1414
|
taxon_match."*Overall_score",
|
1415
|
taxon_match."*Name_matched",
|
1416
|
taxon_match."*Name_matched_rank",
|
1417
|
taxon_match."*Name_score",
|
1418
|
taxon_match."*Name_matched_author",
|
1419
|
taxon_match."*Name_matched_url",
|
1420
|
taxon_match."*Author_matched",
|
1421
|
taxon_match."*Author_score",
|
1422
|
taxon_match."*Family_matched",
|
1423
|
taxon_match."*Family_score",
|
1424
|
taxon_match."*Name_matched_accepted_family",
|
1425
|
taxon_match."*Genus_matched",
|
1426
|
taxon_match."*Genus_score",
|
1427
|
taxon_match."*Specific_epithet_matched",
|
1428
|
taxon_match."*Specific_epithet_score",
|
1429
|
taxon_match."*Infraspecific_rank",
|
1430
|
taxon_match."*Infraspecific_epithet_matched",
|
1431
|
taxon_match."*Infraspecific_epithet_score",
|
1432
|
taxon_match."*Infraspecific_rank_2",
|
1433
|
taxon_match."*Infraspecific_epithet_2_matched",
|
1434
|
taxon_match."*Infraspecific_epithet_2_score",
|
1435
|
taxon_match."*Annotations",
|
1436
|
taxon_match."*Unmatched_terms",
|
1437
|
taxon_match."*Taxonomic_status",
|
1438
|
taxon_match."*Accepted_name",
|
1439
|
taxon_match."*Accepted_name_author",
|
1440
|
taxon_match."*Accepted_name_rank",
|
1441
|
taxon_match."*Accepted_name_url",
|
1442
|
taxon_match."*Accepted_name_species",
|
1443
|
taxon_match."*Accepted_name_family",
|
1444
|
taxon_match."*Selected",
|
1445
|
taxon_match."*Source",
|
1446
|
taxon_match."*Warnings",
|
1447
|
taxon_match."*Accepted_name_lsid",
|
1448
|
taxon_match.is_valid_match,
|
1449
|
taxon_match."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org",
|
1450
|
taxon_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1451
|
taxon_match."matched~Name[_no_author]___@TNRS__@vegpath.org",
|
1452
|
taxon_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1453
|
taxon_match.matched_has_accepted,
|
1454
|
taxon_match."Accepted_family__@TNRS__@vegpath.org",
|
1455
|
taxon_match."Accepted_species[_binomial]__@TNRS__@vegpath.org",
|
1456
|
taxon_match."__accepted_{genus,specific_epithet,infra_{rank,epithet}}",
|
1457
|
taxon_match."[accepted_]genus__@DwC__@vegpath.org",
|
1458
|
taxon_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1459
|
taxon_match."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org",
|
1460
|
taxon_match."__accepted_infraspecific_{rank,epithet}",
|
1461
|
taxon_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1462
|
taxon_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1463
|
taxon_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1464
|
taxon_match."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org",
|
1465
|
taxon_match."[scrubbed_]taxonRank__@DwC__@vegpath.org",
|
1466
|
taxon_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org",
|
1467
|
taxon_match."[scrubbed_]genus__@DwC__@vegpath.org",
|
1468
|
taxon_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org",
|
1469
|
taxon_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1470
|
taxon_match."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org",
|
1471
|
taxon_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1472
|
taxon_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org",
|
1473
|
taxon_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1474
|
taxon_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org",
|
1475
|
taxon_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1476
|
FROM taxon_match
|
1477
|
WHERE (taxon_match."*Selected" = 'true'::text);
|
1478
|
|
1479
|
|
1480
|
--
|
1481
|
-- Name: VIEW taxon_best_match; Type: COMMENT; Schema: TNRS; Owner: -
|
1482
|
--
|
1483
|
|
1484
|
COMMENT ON VIEW taxon_best_match IS '
|
1485
|
to modify:
|
1486
|
SELECT util.recreate_view(''"TNRS"."taxon_best_match"'', $$
|
1487
|
SELECT __
|
1488
|
$$);
|
1489
|
';
|
1490
|
|
1491
|
|
1492
|
--
|
1493
|
-- Name: taxon_match_input; Type: VIEW; Schema: TNRS; Owner: -
|
1494
|
--
|
1495
|
|
1496
|
CREATE VIEW taxon_match_input AS
|
1497
|
SELECT taxon_match."*Name_number" AS "Name_number",
|
1498
|
taxon_match."*Name_submitted" AS "Name_submitted",
|
1499
|
taxon_match."*Overall_score" AS "Overall_score",
|
1500
|
taxon_match."*Name_matched" AS "Name_matched",
|
1501
|
taxon_match."*Name_matched_rank" AS "Name_matched_rank",
|
1502
|
taxon_match."*Name_score" AS "Name_score",
|
1503
|
taxon_match."*Name_matched_author" AS "Name_matched_author",
|
1504
|
taxon_match."*Name_matched_url" AS "Name_matched_url",
|
1505
|
taxon_match."*Author_matched" AS "Author_matched",
|
1506
|
taxon_match."*Author_score" AS "Author_score",
|
1507
|
taxon_match."*Family_matched" AS "Family_matched",
|
1508
|
taxon_match."*Family_score" AS "Family_score",
|
1509
|
taxon_match."*Name_matched_accepted_family" AS "Name_matched_accepted_family",
|
1510
|
taxon_match."*Genus_matched" AS "Genus_matched",
|
1511
|
taxon_match."*Genus_score" AS "Genus_score",
|
1512
|
taxon_match."*Specific_epithet_matched" AS "Specific_epithet_matched",
|
1513
|
taxon_match."*Specific_epithet_score" AS "Specific_epithet_score",
|
1514
|
taxon_match."*Infraspecific_rank" AS "Infraspecific_rank",
|
1515
|
taxon_match."*Infraspecific_epithet_matched" AS "Infraspecific_epithet_matched",
|
1516
|
taxon_match."*Infraspecific_epithet_score" AS "Infraspecific_epithet_score",
|
1517
|
taxon_match."*Infraspecific_rank_2" AS "Infraspecific_rank_2",
|
1518
|
taxon_match."*Infraspecific_epithet_2_matched" AS "Infraspecific_epithet_2_matched",
|
1519
|
taxon_match."*Infraspecific_epithet_2_score" AS "Infraspecific_epithet_2_score",
|
1520
|
taxon_match."*Annotations" AS "Annotations",
|
1521
|
taxon_match."*Unmatched_terms" AS "Unmatched_terms",
|
1522
|
taxon_match."*Taxonomic_status" AS "Taxonomic_status",
|
1523
|
taxon_match."*Accepted_name" AS "Accepted_name",
|
1524
|
taxon_match."*Accepted_name_author" AS "Accepted_name_author",
|
1525
|
taxon_match."*Accepted_name_rank" AS "Accepted_name_rank",
|
1526
|
taxon_match."*Accepted_name_url" AS "Accepted_name_url",
|
1527
|
taxon_match."*Accepted_name_species" AS "Accepted_name_species",
|
1528
|
taxon_match."*Accepted_name_family" AS "Accepted_name_family",
|
1529
|
taxon_match."*Selected" AS "Selected",
|
1530
|
taxon_match."*Source" AS "Source",
|
1531
|
taxon_match."*Warnings" AS "Warnings",
|
1532
|
taxon_match."*Accepted_name_lsid" AS "Accepted_name_lsid"
|
1533
|
FROM taxon_match;
|
1534
|
|
1535
|
|
1536
|
--
|
1537
|
-- Name: taxon_match_input__copy_to; Type: TABLE; Schema: TNRS; Owner: -; Tablespace:
|
1538
|
--
|
1539
|
|
1540
|
CREATE TABLE taxon_match_input__copy_to (
|
1541
|
"Name_number" integer,
|
1542
|
"Name_submitted" text,
|
1543
|
"Overall_score" double precision,
|
1544
|
"Name_matched" text,
|
1545
|
"Name_matched_rank" text,
|
1546
|
"Name_score" double precision,
|
1547
|
"Name_matched_author" text,
|
1548
|
"Name_matched_url" text,
|
1549
|
"Author_matched" text,
|
1550
|
"Author_score" double precision,
|
1551
|
"Family_matched" text,
|
1552
|
"Family_score" double precision,
|
1553
|
"Name_matched_accepted_family" text,
|
1554
|
"Genus_matched" text,
|
1555
|
"Genus_score" double precision,
|
1556
|
"Specific_epithet_matched" text,
|
1557
|
"Specific_epithet_score" double precision,
|
1558
|
"Infraspecific_rank" text,
|
1559
|
"Infraspecific_epithet_matched" text,
|
1560
|
"Infraspecific_epithet_score" double precision,
|
1561
|
"Infraspecific_rank_2" text,
|
1562
|
"Infraspecific_epithet_2_matched" text,
|
1563
|
"Infraspecific_epithet_2_score" double precision,
|
1564
|
"Annotations" text,
|
1565
|
"Unmatched_terms" text,
|
1566
|
"Taxonomic_status" text,
|
1567
|
"Accepted_name" text,
|
1568
|
"Accepted_name_author" text,
|
1569
|
"Accepted_name_rank" text,
|
1570
|
"Accepted_name_url" text,
|
1571
|
"Accepted_name_species" text,
|
1572
|
"Accepted_name_family" text,
|
1573
|
"Selected" text,
|
1574
|
"Source" text,
|
1575
|
"Warnings" text,
|
1576
|
"Accepted_name_lsid" text
|
1577
|
);
|
1578
|
|
1579
|
|
1580
|
--
|
1581
|
-- Name: taxon_scrub; Type: VIEW; Schema: TNRS; Owner: -
|
1582
|
--
|
1583
|
|
1584
|
CREATE VIEW taxon_scrub AS
|
1585
|
SELECT taxon_best_match.batch,
|
1586
|
taxon_best_match.match_num,
|
1587
|
taxon_best_match."*Name_number",
|
1588
|
taxon_best_match."*Name_submitted",
|
1589
|
taxon_best_match."*Overall_score",
|
1590
|
taxon_best_match."*Name_matched",
|
1591
|
taxon_best_match."*Name_matched_rank",
|
1592
|
taxon_best_match."*Name_score",
|
1593
|
taxon_best_match."*Name_matched_author",
|
1594
|
taxon_best_match."*Name_matched_url",
|
1595
|
taxon_best_match."*Author_matched",
|
1596
|
taxon_best_match."*Author_score",
|
1597
|
taxon_best_match."*Family_matched",
|
1598
|
taxon_best_match."*Family_score",
|
1599
|
taxon_best_match."*Name_matched_accepted_family",
|
1600
|
taxon_best_match."*Genus_matched",
|
1601
|
taxon_best_match."*Genus_score",
|
1602
|
taxon_best_match."*Specific_epithet_matched",
|
1603
|
taxon_best_match."*Specific_epithet_score",
|
1604
|
taxon_best_match."*Infraspecific_rank",
|
1605
|
taxon_best_match."*Infraspecific_epithet_matched",
|
1606
|
taxon_best_match."*Infraspecific_epithet_score",
|
1607
|
taxon_best_match."*Infraspecific_rank_2",
|
1608
|
taxon_best_match."*Infraspecific_epithet_2_matched",
|
1609
|
taxon_best_match."*Infraspecific_epithet_2_score",
|
1610
|
taxon_best_match."*Annotations",
|
1611
|
taxon_best_match."*Unmatched_terms",
|
1612
|
taxon_best_match."*Taxonomic_status",
|
1613
|
taxon_best_match."*Accepted_name",
|
1614
|
taxon_best_match."*Accepted_name_author",
|
1615
|
taxon_best_match."*Accepted_name_rank",
|
1616
|
taxon_best_match."*Accepted_name_url",
|
1617
|
taxon_best_match."*Accepted_name_species",
|
1618
|
taxon_best_match."*Accepted_name_family",
|
1619
|
taxon_best_match."*Selected",
|
1620
|
taxon_best_match."*Source",
|
1621
|
taxon_best_match."*Warnings",
|
1622
|
taxon_best_match."*Accepted_name_lsid",
|
1623
|
taxon_best_match.is_valid_match,
|
1624
|
taxon_best_match."[parsed_]morphospecies[_suffix]__@Brad__.morphosp@vegpath.org",
|
1625
|
taxon_best_match."[matched_]species[_binomial]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1626
|
taxon_best_match."matched~Name[_no_author]___@TNRS__@vegpath.org",
|
1627
|
taxon_best_match."[matched_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1628
|
taxon_best_match.matched_has_accepted,
|
1629
|
taxon_best_match."Accepted_family__@TNRS__@vegpath.org",
|
1630
|
taxon_best_match."Accepted_species[_binomial]__@TNRS__@vegpath.org",
|
1631
|
taxon_best_match."__accepted_{genus,specific_epithet,infra_{rank,epithet}}",
|
1632
|
taxon_best_match."[accepted_]genus__@DwC__@vegpath.org",
|
1633
|
taxon_best_match."[accepted_]specificEpithet__@DwC__@vegpath.org",
|
1634
|
taxon_best_match."[accepted_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org",
|
1635
|
taxon_best_match."__accepted_infraspecific_{rank,epithet}",
|
1636
|
taxon_best_match."[accepted_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1637
|
taxon_best_match."[accepted_]infraspecificEpithet__@DwC__@vegpath.org",
|
1638
|
taxon_best_match."[accepted_]scientificName[_with_author]__@DwC__@vegpath.org",
|
1639
|
taxon_best_match."[scrubbed_]taxonomicStatus__@DwC__@vegpath.org",
|
1640
|
taxon_best_match."[scrubbed_]taxonRank__@DwC__@vegpath.org",
|
1641
|
taxon_best_match."[scrubbed_]family~(-Accepted_-)__@TNRS__@vegpath.org",
|
1642
|
taxon_best_match."[scrubbed_]genus__@DwC__@vegpath.org",
|
1643
|
taxon_best_match."[scrubbed_]specificEpithet__@DwC__@vegpath.org",
|
1644
|
taxon_best_match."[scrubbed_]species[_binom]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1645
|
taxon_best_match."[scrubbed_]morphospecies[_binomial]__@Brad__.TNRS@vegpath.org",
|
1646
|
taxon_best_match."[scrubbed_]Infraspecific_rank[_abbr]__@TNRS__@vegpath.org",
|
1647
|
taxon_best_match."[scrubbed_]infraspecificEpithet__@DwC__@vegpath.org",
|
1648
|
taxon_best_match."[scrubbed_]name[_no_author]~(-Accepted_-)__@TNRS__@vegpath.org",
|
1649
|
taxon_best_match."[scrubbed_]author~(-Accepted_-)__@TNRS__@vegpath.org",
|
1650
|
taxon_best_match."[scrubbed_]scientificName[_with_author]__@DwC__@vegpath.org"
|
1651
|
FROM taxon_best_match
|
1652
|
WHERE taxon_best_match.is_valid_match;
|
1653
|
|
1654
|
|
1655
|
--
|
1656
|
-- Name: VIEW taxon_scrub; Type: COMMENT; Schema: TNRS; Owner: -
|
1657
|
--
|
1658
|
|
1659
|
COMMENT ON VIEW taxon_scrub IS '
|
1660
|
to modify:
|
1661
|
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
|
1662
|
SELECT __
|
1663
|
$$);
|
1664
|
|
1665
|
to merge synonymous columns:
|
1666
|
# temporarily move correct col out of the way, to allow renaming synonym col:
|
1667
|
ALTER TABLE "TNRS".taxon_scrub RENAME "correct_col" TO "_correct_col";
|
1668
|
## also perform the rename in any dependent .* views (currently there are none)
|
1669
|
# rename columns to replace:
|
1670
|
ALTER TABLE "TNRS".taxon_scrub RENAME "synonym_col" TO "correct_col";
|
1671
|
## also perform the rename in any dependent .* views (currently there are none)
|
1672
|
# remove duplicate cols and now-unnecessary CASE wrappers
|
1673
|
SELECT util.recreate_view(''"TNRS".taxon_scrub'', $$
|
1674
|
SELECT __ -- with the CASE-wrapped synonym col removed
|
1675
|
$$);
|
1676
|
';
|
1677
|
|
1678
|
|
1679
|
--
|
1680
|
-- Name: batch_download_settings_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1681
|
--
|
1682
|
|
1683
|
ALTER TABLE ONLY batch_download_settings
|
1684
|
ADD CONSTRAINT batch_download_settings_pkey PRIMARY KEY (id);
|
1685
|
|
1686
|
|
1687
|
--
|
1688
|
-- Name: batch_id_by_time_key; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1689
|
--
|
1690
|
|
1691
|
ALTER TABLE ONLY batch
|
1692
|
ADD CONSTRAINT batch_id_by_time_key UNIQUE (id_by_time);
|
1693
|
|
1694
|
|
1695
|
--
|
1696
|
-- Name: batch_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1697
|
--
|
1698
|
|
1699
|
ALTER TABLE ONLY batch
|
1700
|
ADD CONSTRAINT batch_pkey PRIMARY KEY (id);
|
1701
|
|
1702
|
|
1703
|
--
|
1704
|
-- Name: client_version_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1705
|
--
|
1706
|
|
1707
|
ALTER TABLE ONLY client_version
|
1708
|
ADD CONSTRAINT client_version_pkey PRIMARY KEY (id);
|
1709
|
|
1710
|
|
1711
|
--
|
1712
|
-- Name: taxon_match_pkey; Type: CONSTRAINT; Schema: TNRS; Owner: -; Tablespace:
|
1713
|
--
|
1714
|
|
1715
|
ALTER TABLE ONLY taxon_match
|
1716
|
ADD CONSTRAINT taxon_match_pkey PRIMARY KEY (batch, match_num);
|
1717
|
|
1718
|
ALTER TABLE taxon_match CLUSTER ON taxon_match_pkey;
|
1719
|
|
1720
|
|
1721
|
--
|
1722
|
-- Name: batch_client_version_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1723
|
--
|
1724
|
|
1725
|
CREATE INDEX batch_client_version_idx ON batch USING btree (client_version);
|
1726
|
|
1727
|
|
1728
|
--
|
1729
|
-- Name: taxon_best_match__valid_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1730
|
--
|
1731
|
|
1732
|
CREATE INDEX taxon_best_match__valid_match ON taxon_match USING btree ("*Name_submitted") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
|
1733
|
|
1734
|
|
1735
|
--
|
1736
|
-- Name: taxon_match_Name_submitted_idx; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1737
|
--
|
1738
|
|
1739
|
CREATE INDEX "taxon_match_Name_submitted_idx" ON taxon_match USING btree ("*Name_submitted");
|
1740
|
|
1741
|
|
1742
|
--
|
1743
|
-- Name: taxon_match__one_selected_match; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1744
|
--
|
1745
|
|
1746
|
CREATE UNIQUE INDEX taxon_match__one_selected_match ON taxon_match USING btree (batch, "*Name_number") WHERE ("*Selected" = 'true'::text);
|
1747
|
|
1748
|
|
1749
|
--
|
1750
|
-- Name: taxon_scrub_best_match_jerry_lu; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1751
|
--
|
1752
|
|
1753
|
CREATE INDEX taxon_scrub_best_match_jerry_lu ON taxon_match USING btree ("*Name_submitted", "*Name_score" DESC, "*Overall_score" DESC);
|
1754
|
|
1755
|
|
1756
|
--
|
1757
|
-- Name: taxon_scrub_by_family; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1758
|
--
|
1759
|
|
1760
|
CREATE INDEX taxon_scrub_by_family ON taxon_match USING btree ("Accepted_family__@TNRS__@vegpath.org") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
|
1761
|
|
1762
|
|
1763
|
--
|
1764
|
-- Name: taxon_scrub_by_name; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1765
|
--
|
1766
|
|
1767
|
CREATE INDEX taxon_scrub_by_name ON taxon_match USING btree ("*Accepted_name") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
|
1768
|
|
1769
|
|
1770
|
--
|
1771
|
-- Name: taxon_scrub_by_species_binomial; Type: INDEX; Schema: TNRS; Owner: -; Tablespace:
|
1772
|
--
|
1773
|
|
1774
|
CREATE INDEX taxon_scrub_by_species_binomial ON taxon_match USING btree ("Accepted_species[_binomial]__@TNRS__@vegpath.org", "Accepted_family__@TNRS__@vegpath.org") WHERE (("*Selected" = 'true'::text) AND is_valid_match);
|
1775
|
|
1776
|
|
1777
|
--
|
1778
|
-- Name: batch__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1779
|
--
|
1780
|
|
1781
|
CREATE TRIGGER batch__fill BEFORE INSERT OR UPDATE ON batch FOR EACH ROW EXECUTE PROCEDURE batch__fill();
|
1782
|
|
1783
|
|
1784
|
--
|
1785
|
-- Name: taxon_match__batch_begin; Type: TRIGGER; Schema: TNRS; Owner: -
|
1786
|
--
|
1787
|
|
1788
|
CREATE TRIGGER taxon_match__batch_begin BEFORE INSERT ON taxon_match_input__copy_to FOR EACH STATEMENT EXECUTE PROCEDURE taxon_match__batch_begin();
|
1789
|
|
1790
|
|
1791
|
--
|
1792
|
-- Name: taxon_match__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1793
|
--
|
1794
|
|
1795
|
CREATE TRIGGER taxon_match__fill BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill();
|
1796
|
|
1797
|
|
1798
|
--
|
1799
|
-- Name: taxon_match__fill_derived; Type: TRIGGER; Schema: TNRS; Owner: -
|
1800
|
--
|
1801
|
|
1802
|
CREATE TRIGGER taxon_match__fill_derived BEFORE INSERT OR UPDATE ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__fill_derived();
|
1803
|
|
1804
|
|
1805
|
--
|
1806
|
-- Name: taxon_match__match_num__fill; Type: TRIGGER; Schema: TNRS; Owner: -
|
1807
|
--
|
1808
|
|
1809
|
CREATE TRIGGER taxon_match__match_num__fill BEFORE INSERT ON taxon_match FOR EACH ROW EXECUTE PROCEDURE taxon_match__match_num__fill();
|
1810
|
|
1811
|
|
1812
|
--
|
1813
|
-- Name: taxon_match_input__copy_to__insert; Type: TRIGGER; Schema: TNRS; Owner: -
|
1814
|
--
|
1815
|
|
1816
|
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();
|
1817
|
|
1818
|
|
1819
|
--
|
1820
|
-- Name: batch_client_version_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1821
|
--
|
1822
|
|
1823
|
ALTER TABLE ONLY batch
|
1824
|
ADD CONSTRAINT batch_client_version_fkey FOREIGN KEY (client_version) REFERENCES client_version(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1825
|
|
1826
|
|
1827
|
--
|
1828
|
-- Name: batch_download_settings_id_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1829
|
--
|
1830
|
|
1831
|
ALTER TABLE ONLY batch_download_settings
|
1832
|
ADD CONSTRAINT batch_download_settings_id_fkey FOREIGN KEY (id) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1833
|
|
1834
|
|
1835
|
--
|
1836
|
-- Name: taxon_match_batch_fkey; Type: FK CONSTRAINT; Schema: TNRS; Owner: -
|
1837
|
--
|
1838
|
|
1839
|
ALTER TABLE ONLY taxon_match
|
1840
|
ADD CONSTRAINT taxon_match_batch_fkey FOREIGN KEY (batch) REFERENCES batch(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
1841
|
|
1842
|
|
1843
|
--
|
1844
|
-- Name: TNRS; Type: ACL; Schema: -; Owner: -
|
1845
|
--
|
1846
|
|
1847
|
REVOKE ALL ON SCHEMA "TNRS" FROM PUBLIC;
|
1848
|
REVOKE ALL ON SCHEMA "TNRS" FROM bien;
|
1849
|
GRANT ALL ON SCHEMA "TNRS" TO bien;
|
1850
|
GRANT USAGE ON SCHEMA "TNRS" TO bien_read;
|
1851
|
|
1852
|
|
1853
|
--
|
1854
|
-- Name: taxon_match; Type: ACL; Schema: TNRS; Owner: -
|
1855
|
--
|
1856
|
|
1857
|
REVOKE ALL ON TABLE taxon_match FROM PUBLIC;
|
1858
|
REVOKE ALL ON TABLE taxon_match FROM bien;
|
1859
|
GRANT ALL ON TABLE taxon_match TO bien;
|
1860
|
GRANT SELECT ON TABLE taxon_match TO bien_read;
|
1861
|
|
1862
|
|
1863
|
--
|
1864
|
-- Name: taxon_best_match; Type: ACL; Schema: TNRS; Owner: -
|
1865
|
--
|
1866
|
|
1867
|
REVOKE ALL ON TABLE taxon_best_match FROM PUBLIC;
|
1868
|
REVOKE ALL ON TABLE taxon_best_match FROM bien;
|
1869
|
GRANT ALL ON TABLE taxon_best_match TO bien;
|
1870
|
GRANT SELECT ON TABLE taxon_best_match TO bien_read;
|
1871
|
|
1872
|
|
1873
|
--
|
1874
|
-- Name: taxon_match_input; Type: ACL; Schema: TNRS; Owner: -
|
1875
|
--
|
1876
|
|
1877
|
REVOKE ALL ON TABLE taxon_match_input FROM PUBLIC;
|
1878
|
REVOKE ALL ON TABLE taxon_match_input FROM bien;
|
1879
|
GRANT ALL ON TABLE taxon_match_input TO bien;
|
1880
|
GRANT SELECT ON TABLE taxon_match_input TO bien_read;
|
1881
|
|
1882
|
|
1883
|
--
|
1884
|
-- Name: taxon_scrub; Type: ACL; Schema: TNRS; Owner: -
|
1885
|
--
|
1886
|
|
1887
|
REVOKE ALL ON TABLE taxon_scrub FROM PUBLIC;
|
1888
|
REVOKE ALL ON TABLE taxon_scrub FROM bien;
|
1889
|
GRANT ALL ON TABLE taxon_scrub TO bien;
|
1890
|
GRANT SELECT ON TABLE taxon_scrub TO bien_read;
|
1891
|
|
1892
|
|
1893
|
--
|
1894
|
-- PostgreSQL database dump complete
|
1895
|
--
|
1896
|
|