1
|
CREATE TABLE tnrs
|
2
|
(
|
3
|
"Time_submitted" timestamp with time zone,
|
4
|
"Name_number" text,
|
5
|
"Name_submitted" text NOT NULL,
|
6
|
"Overall_score" text,
|
7
|
"Name_matched" text,
|
8
|
"Name_matched_rank" text,
|
9
|
"Name_score" text,
|
10
|
"Name_matched_author" text,
|
11
|
"Name_matched_url" text,
|
12
|
"Author_matched" text,
|
13
|
"Author_score" text,
|
14
|
"Family_matched" text,
|
15
|
"Family_score" text,
|
16
|
"Name_matched_accepted_family" text,
|
17
|
"Genus_matched" text,
|
18
|
"Genus_score" text,
|
19
|
"Specific_epithet_matched" text,
|
20
|
"Specific_epithet_score" text,
|
21
|
"Infraspecific_rank" text,
|
22
|
"Infraspecific_epithet_matched" text,
|
23
|
"Infraspecific_epithet_score" text,
|
24
|
"Infraspecific_rank_2" text,
|
25
|
"Infraspecific_epithet_2_matched" text,
|
26
|
"Infraspecific_epithet_2_score" text,
|
27
|
"Annotations" text,
|
28
|
"Unmatched_terms" text,
|
29
|
"Taxonomic_status" text,
|
30
|
"Accepted_name" text,
|
31
|
"Accepted_name_author" text,
|
32
|
"Accepted_name_rank" text,
|
33
|
"Accepted_name_url" text,
|
34
|
"Accepted_name_species" text,
|
35
|
"Accepted_name_family" text,
|
36
|
"Selected" text,
|
37
|
"Source" text,
|
38
|
"Warnings" text,
|
39
|
"Accepted_name_lsid" text,
|
40
|
"Accepted_scientific_name" text,
|
41
|
CONSTRAINT tnrs_pkey PRIMARY KEY ("Name_submitted" )
|
42
|
)
|
43
|
WITH (
|
44
|
OIDS=FALSE
|
45
|
);
|
46
|
|
47
|
CREATE OR REPLACE FUNCTION tnrs_populate_accepted_scientific_name()
|
48
|
RETURNS trigger AS
|
49
|
$BODY$
|
50
|
BEGIN
|
51
|
new."Accepted_scientific_name" = NULLIF(array_to_string(ARRAY[
|
52
|
NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
|
53
|
, new."Accepted_name"
|
54
|
, new."Accepted_name_author"
|
55
|
], ' '), '');
|
56
|
|
57
|
RETURN new;
|
58
|
END;
|
59
|
$BODY$
|
60
|
LANGUAGE plpgsql VOLATILE
|
61
|
COST 100;
|
62
|
|
63
|
CREATE TRIGGER tnrs_populate_accepted_scientific_name
|
64
|
BEFORE INSERT OR UPDATE
|
65
|
ON tnrs
|
66
|
FOR EACH ROW
|
67
|
EXECUTE PROCEDURE tnrs_populate_accepted_scientific_name();
|
68
|
|
69
|
|
70
|
CREATE OR REPLACE VIEW "tnrs+accepted" AS
|
71
|
SELECT
|
72
|
tnrs.*
|
73
|
, tnrs_accepted."Time_submitted" AS "Accepted_name.Time_submitted"
|
74
|
, tnrs_accepted."Name_number" AS "Accepted_name.Name_number"
|
75
|
, tnrs_accepted."Name_submitted" AS "Accepted_name.Name_submitted"
|
76
|
, tnrs_accepted."Overall_score" AS "Accepted_name.Overall_score"
|
77
|
, tnrs_accepted."Name_matched" AS "Accepted_name.Name_matched"
|
78
|
, tnrs_accepted."Name_matched_rank" AS "Accepted_name.Name_matched_rank"
|
79
|
, tnrs_accepted."Name_score" AS "Accepted_name.Name_score"
|
80
|
, tnrs_accepted."Name_matched_author" AS "Accepted_name.Name_matched_author"
|
81
|
, tnrs_accepted."Name_matched_url" AS "Accepted_name.Name_matched_url"
|
82
|
, tnrs_accepted."Author_matched" AS "Accepted_name.Author_matched"
|
83
|
, tnrs_accepted."Author_score" AS "Accepted_name.Author_score"
|
84
|
, tnrs_accepted."Family_matched" AS "Accepted_name.Family_matched"
|
85
|
, tnrs_accepted."Family_score" AS "Accepted_name.Family_score"
|
86
|
, tnrs_accepted."Name_matched_accepted_family" AS "Accepted_name.Name_matched_accepted_family"
|
87
|
, tnrs_accepted."Genus_matched" AS "Accepted_name.Genus_matched"
|
88
|
, tnrs_accepted."Genus_score" AS "Accepted_name.Genus_score"
|
89
|
, tnrs_accepted."Specific_epithet_matched" AS "Accepted_name.Specific_epithet_matched"
|
90
|
, tnrs_accepted."Specific_epithet_score" AS "Accepted_name.Specific_epithet_score"
|
91
|
, tnrs_accepted."Infraspecific_rank" AS "Accepted_name.Infraspecific_rank"
|
92
|
, tnrs_accepted."Infraspecific_epithet_matched" AS "Accepted_name.Infraspecific_epithet_matched"
|
93
|
, tnrs_accepted."Infraspecific_epithet_score" AS "Accepted_name.Infraspecific_epithet_score"
|
94
|
, tnrs_accepted."Infraspecific_rank_2" AS "Accepted_name.Infraspecific_rank_2"
|
95
|
, tnrs_accepted."Infraspecific_epithet_2_matched" AS "Accepted_name.Infraspecific_epithet_2_matched"
|
96
|
, tnrs_accepted."Infraspecific_epithet_2_score" AS "Accepted_name.Infraspecific_epithet_2_score"
|
97
|
, tnrs_accepted."Annotations" AS "Accepted_name.Annotations"
|
98
|
, tnrs_accepted."Unmatched_terms" AS "Accepted_name.Unmatched_terms"
|
99
|
, tnrs_accepted."Taxonomic_status" AS "Accepted_name.Taxonomic_status"
|
100
|
, tnrs_accepted."Accepted_name" AS "Accepted_name.Accepted_name"
|
101
|
, tnrs_accepted."Accepted_name_author" AS "Accepted_name.Accepted_name_author"
|
102
|
, tnrs_accepted."Accepted_name_rank" AS "Accepted_name.Accepted_name_rank"
|
103
|
, tnrs_accepted."Accepted_name_url" AS "Accepted_name.Accepted_name_url"
|
104
|
, tnrs_accepted."Accepted_name_species" AS "Accepted_name.Accepted_name_species"
|
105
|
, tnrs_accepted."Accepted_name_family" AS "Accepted_name.Accepted_name_family"
|
106
|
, tnrs_accepted."Selected" AS "Accepted_name.Selected"
|
107
|
, tnrs_accepted."Source" AS "Accepted_name.Source"
|
108
|
, tnrs_accepted."Warnings" AS "Accepted_name.Warnings"
|
109
|
, tnrs_accepted."Accepted_name_lsid" AS "Accepted_name.Accepted_name_lsid"
|
110
|
, tnrs_accepted."Accepted_scientific_name" AS "Accepted_name.Accepted_scientific_name"
|
111
|
FROM tnrs
|
112
|
LEFT JOIN tnrs tnrs_accepted ON
|
113
|
tnrs_accepted."Name_submitted" = tnrs."Accepted_scientific_name"
|
114
|
;
|