1
|
CREATE OR REPLACE FUNCTION score_ok(score double precision)
|
2
|
RETURNS boolean AS
|
3
|
$BODY$
|
4
|
SELECT $1 >= 0.8
|
5
|
$BODY$
|
6
|
LANGUAGE sql VOLATILE
|
7
|
COST 100;
|
8
|
|
9
|
|
10
|
CREATE TABLE tnrs
|
11
|
(
|
12
|
"Time_submitted" timestamp with time zone,
|
13
|
"Name_number" text,
|
14
|
"Name_submitted" text NOT NULL,
|
15
|
"Overall_score" text,
|
16
|
"Name_matched" text,
|
17
|
"Name_matched_rank" text,
|
18
|
"Name_score" text,
|
19
|
"Name_matched_author" text,
|
20
|
"Name_matched_url" text,
|
21
|
"Author_matched" text,
|
22
|
"Author_score" text,
|
23
|
"Family_matched" text,
|
24
|
"Family_score" text,
|
25
|
"Genus_matched" text,
|
26
|
"Genus_score" text,
|
27
|
"Specific_epithet_matched" text,
|
28
|
"Specific_epithet_score" text,
|
29
|
"Infraspecific_rank" text,
|
30
|
"Infraspecific_epithet_matched" text,
|
31
|
"Infraspecific_epithet_score" text,
|
32
|
"Infraspecific_rank_2" text,
|
33
|
"Infraspecific_epithet_2_matched" text,
|
34
|
"Infraspecific_epithet_2_score" text,
|
35
|
"Annotations" text,
|
36
|
"Unmatched_terms" text,
|
37
|
"Taxonomic_status" text,
|
38
|
"Accepted_name" text,
|
39
|
"Accepted_name_author" text,
|
40
|
"Accepted_name_rank" text,
|
41
|
"Accepted_name_url" text,
|
42
|
"Accepted_species" text,
|
43
|
"Accepted_family" text,
|
44
|
"Selected" text,
|
45
|
"Source" text,
|
46
|
"Warnings" text,
|
47
|
"Accepted_name_lsid" text,
|
48
|
"Accepted_scientific_name" text,
|
49
|
"Max_score" double precision,
|
50
|
CONSTRAINT tnrs_pkey PRIMARY KEY ("Name_submitted" )
|
51
|
)
|
52
|
WITH (
|
53
|
OIDS=FALSE
|
54
|
);
|
55
|
|
56
|
CREATE UNIQUE INDEX tnrs_score_ok
|
57
|
ON tnrs
|
58
|
USING btree
|
59
|
("Name_submitted" )
|
60
|
WHERE score_ok("Max_score");
|
61
|
|
62
|
CREATE OR REPLACE FUNCTION tnrs_populate_fields()
|
63
|
RETURNS trigger AS
|
64
|
$BODY$
|
65
|
BEGIN
|
66
|
new."Accepted_scientific_name" = NULLIF(concat_ws(' '
|
67
|
, NULLIF(NULLIF(new."Accepted_family", 'Unknown'), new."Accepted_name")
|
68
|
, new."Accepted_name"
|
69
|
, new."Accepted_name_author"
|
70
|
), '');
|
71
|
new."Max_score" = GREATEST(
|
72
|
new."Overall_score"::double precision
|
73
|
, new."Family_score"::double precision
|
74
|
, new."Genus_score"::double precision
|
75
|
, new."Specific_epithet_score"::double precision
|
76
|
);
|
77
|
|
78
|
RETURN new;
|
79
|
END;
|
80
|
$BODY$
|
81
|
LANGUAGE plpgsql VOLATILE
|
82
|
COST 100;
|
83
|
|
84
|
CREATE TRIGGER tnrs_populate_fields
|
85
|
BEFORE INSERT OR UPDATE
|
86
|
ON tnrs
|
87
|
FOR EACH ROW
|
88
|
EXECUTE PROCEDURE tnrs_populate_fields();
|
89
|
|
90
|
|
91
|
CREATE OR REPLACE VIEW "MatchedTaxon" AS
|
92
|
SELECT
|
93
|
"Time_submitted" AS "*Name_matched.Time_submitted"
|
94
|
, "Name_submitted" AS "concatenatedScientificName"
|
95
|
, "Name_matched" AS "matchedTaxonName"
|
96
|
, "Name_matched_rank" AS "matchedTaxonRank"
|
97
|
, "Name_score" AS "*Name_matched.Name_score"
|
98
|
, "Name_matched_author" AS "matchedScientificNameAuthorship"
|
99
|
, "Name_matched_url" AS "matchedScientificNameID"
|
100
|
, "Author_score" AS "*Name_matched.Author_score"
|
101
|
, "Family_score" AS "matchedFamilyConfidence_fraction"
|
102
|
, "Genus_matched" AS "matchedGenus"
|
103
|
, "Genus_score" AS "matchedGenusConfidence_fraction"
|
104
|
, "Specific_epithet_matched" AS "matchedSpecificEpithet"
|
105
|
, "Specific_epithet_score" AS "matchedSpeciesConfidence_fraction"
|
106
|
, "Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet"
|
107
|
, "Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score"
|
108
|
, "Annotations" AS "identificationQualifier"
|
109
|
, "Unmatched_terms" AS "morphospeciesSuffix"
|
110
|
, "Taxonomic_status" AS "taxonomicStatus"
|
111
|
, "Accepted_name" AS "acceptedTaxonName"
|
112
|
, "Accepted_name_author" AS "acceptedScientificNameAuthorship"
|
113
|
, "Accepted_name_rank" AS "acceptedTaxonRank"
|
114
|
, "Accepted_name_url" AS "acceptedScientificNameID"
|
115
|
, "Accepted_species" AS "*Name_matched.Accepted_species"
|
116
|
, "Accepted_family" AS "acceptedFamily"
|
117
|
, "Selected" AS "*Name_matched.Selected"
|
118
|
, "Source" AS "*Name_matched.Source"
|
119
|
, "Warnings" AS "*Name_matched.Warnings"
|
120
|
, "Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid"
|
121
|
, "Accepted_scientific_name" AS "acceptedScientificName"
|
122
|
, "Max_score" AS "matchedTaxonConfidence_fraction"
|
123
|
FROM tnrs;
|
124
|
|
125
|
CREATE OR REPLACE VIEW "AcceptedTaxon" AS
|
126
|
SELECT
|
127
|
"Time_submitted" AS "*Accepted_name.Time_submitted"
|
128
|
, "Name_submitted" AS "acceptedScientificName"
|
129
|
, "Genus_matched" AS "acceptedGenus"
|
130
|
, "Specific_epithet_matched" AS "acceptedSpecificEpithet"
|
131
|
, "Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet"
|
132
|
, "Annotations" AS "*Accepted_name.Annotations"
|
133
|
, "Taxonomic_status" AS "acceptedTaxonomicStatus"
|
134
|
, "Selected" AS "*Accepted_name.Selected"
|
135
|
, "Source" AS "*Accepted_name.Source"
|
136
|
, "Warnings" AS "*Accepted_name.Warnings"
|
137
|
, "Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid"
|
138
|
FROM tnrs;
|
139
|
|
140
|
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
|
141
|
SELECT *
|
142
|
FROM "MatchedTaxon"
|
143
|
NATURAL LEFT JOIN "AcceptedTaxon"
|
144
|
WHERE score_ok("matchedTaxonConfidence_fraction");
|
145
|
;
|