Project

General

Profile

1 7844 aaronmk
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 9756 aaronmk
/* IMPORTANT: when changing this table's schema, you must regenerate data.sql:
10
$ <this_file>/../test_taxonomic_names/test_scrub
11
*/
12 5183 aaronmk
CREATE TABLE tnrs
13 5110 aaronmk
(
14 9905 aaronmk
  "Time_submitted" timestamp with time zone NOT NULL DEFAULT now(),
15 9908 aaronmk
  "Name_number" integer NOT NULL,
16 5110 aaronmk
  "Name_submitted" text NOT NULL,
17 9913 aaronmk
  "Overall_score" double precision,
18 5110 aaronmk
  "Name_matched" text,
19
  "Name_matched_rank" text,
20 9913 aaronmk
  "Name_score" double precision,
21 5110 aaronmk
  "Name_matched_author" text,
22
  "Name_matched_url" text,
23
  "Author_matched" text,
24 9913 aaronmk
  "Author_score" double precision,
25 5110 aaronmk
  "Family_matched" text,
26 9913 aaronmk
  "Family_score" double precision,
27 9529 aaronmk
  "Name_matched_accepted_family" text,
28 5110 aaronmk
  "Genus_matched" text,
29 9913 aaronmk
  "Genus_score" double precision,
30 5110 aaronmk
  "Specific_epithet_matched" text,
31 9913 aaronmk
  "Specific_epithet_score" double precision,
32 5110 aaronmk
  "Infraspecific_rank" text,
33
  "Infraspecific_epithet_matched" text,
34 9913 aaronmk
  "Infraspecific_epithet_score" double precision,
35 5110 aaronmk
  "Infraspecific_rank_2" text,
36
  "Infraspecific_epithet_2_matched" text,
37 9913 aaronmk
  "Infraspecific_epithet_2_score" double precision,
38 5110 aaronmk
  "Annotations" text,
39
  "Unmatched_terms" text,
40
  "Taxonomic_status" text,
41
  "Accepted_name" text,
42
  "Accepted_name_author" text,
43
  "Accepted_name_rank" text,
44
  "Accepted_name_url" text,
45 9762 aaronmk
  "Accepted_name_species" text,
46
  "Accepted_name_family" text,
47 5110 aaronmk
  "Selected" text,
48
  "Source" text,
49
  "Warnings" text,
50
  "Accepted_name_lsid" text,
51 7133 aaronmk
  "Accepted_scientific_name" text,
52 7293 aaronmk
  "Max_score" double precision,
53 9972 aaronmk
  "Is_homonym" boolean,
54 9763 aaronmk
  "Is_plant" boolean,
55 9907 aaronmk
  CONSTRAINT tnrs_pkey PRIMARY KEY ("Time_submitted" , "Name_number" ),
56 9906 aaronmk
  CONSTRAINT "tnrs_Name_submitted_key" UNIQUE ("Name_submitted" )
57 5110 aaronmk
)
58
WITH (
59
  OIDS=FALSE
60
);
61 7132 aaronmk
62 7844 aaronmk
CREATE UNIQUE INDEX tnrs_score_ok
63
  ON tnrs
64
  USING btree
65
  ("Name_submitted" )
66
  WHERE score_ok("Max_score");
67
68 9765 aaronmk
/* IMPORTANT: when changing this function, you must regenerate the derived cols:
69 9974 aaronmk
UPDATE "TNRS".tnrs SET "Name_submitted" = "Name_submitted"
70 9767 aaronmk
runtime: 17 min ("4992166 rows affected, 1019907 ms execution time")
71 9765 aaronmk
*/
72 9512 aaronmk
CREATE OR REPLACE FUNCTION tnrs_populate_fields()
73 7134 aaronmk
  RETURNS trigger AS
74
$BODY$
75 9763 aaronmk
DECLARE
76
    "Specific_epithet_is_plant" boolean :=
77
        (CASE
78
        WHEN   new."Infraspecific_epithet_matched"   IS NOT NULL
79
            OR new."Infraspecific_epithet_2_matched" IS NOT NULL
80 9914 aaronmk
            OR new."Specific_epithet_score" >= 0.9 -- fuzzy match
81 9763 aaronmk
            THEN true
82
        ELSE NULL -- ambiguous
83
        END);
84 9972 aaronmk
    family_is_homonym boolean = EXISTS(SELECT * FROM "IRMNG".family_homonym_epithet WHERE "taxonNameOrEpithet" = new."Family_matched");
85
    genus_is_homonym  boolean = EXISTS(SELECT * FROM "IRMNG".genus_homonym_epithet  WHERE "taxonNameOrEpithet" = new."Genus_matched");
86 7134 aaronmk
BEGIN
87 7848 aaronmk
    new."Accepted_scientific_name" = NULLIF(concat_ws(' '
88 9762 aaronmk
        , NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
89 7134 aaronmk
        , new."Accepted_name"
90
        , new."Accepted_name_author"
91 7848 aaronmk
    ), '');
92 7293 aaronmk
    new."Max_score" = GREATEST(
93 9914 aaronmk
          new."Overall_score"
94
        , new."Family_score"
95
        , new."Genus_score"
96
        , new."Specific_epithet_score"
97 7293 aaronmk
    );
98 9972 aaronmk
    new."Is_homonym" = (CASE
99
        WHEN new."Author_matched" IS NOT NULL THEN false -- author disambiguates
100
        ELSE family_is_homonym OR genus_is_homonym
101
        END);
102 9763 aaronmk
    new."Is_plant" = (CASE
103 9973 aaronmk
        WHEN new."Family_score" = 1 AND NOT family_is_homonym -- exact match
104
            THEN true
105
        ELSE -- consider genus
106 9763 aaronmk
            (CASE
107 9914 aaronmk
            WHEN new."Genus_score" =  1    -- exact match
108 9973 aaronmk
                THEN
109
                (CASE
110
                WHEN NOT genus_is_homonym THEN true
111
                ELSE "Specific_epithet_is_plant"
112
                END)
113 9914 aaronmk
            WHEN new."Genus_score" >= 0.85 -- fuzzy match
114 9763 aaronmk
                THEN "Specific_epithet_is_plant"
115
            ELSE NULL -- ambiguous
116
            END)
117
        END);
118 7134 aaronmk
119
    RETURN new;
120
END;
121
$BODY$
122
  LANGUAGE plpgsql VOLATILE
123
  COST 100;
124
125 9512 aaronmk
CREATE TRIGGER tnrs_populate_fields
126 7134 aaronmk
  BEFORE INSERT OR UPDATE
127
  ON tnrs
128
  FOR EACH ROW
129 9512 aaronmk
  EXECUTE PROCEDURE tnrs_populate_fields();
130 7251 aaronmk
131
132 9759 aaronmk
CREATE OR REPLACE VIEW "MatchedTaxon" AS
133 7823 aaronmk
SELECT
134
  "Time_submitted" AS "*Name_matched.Time_submitted"
135 7830 aaronmk
, "Name_submitted" AS "concatenatedScientificName"
136 7829 aaronmk
, "Name_matched" AS "matchedTaxonName"
137 7823 aaronmk
, "Name_matched_rank" AS "matchedTaxonRank"
138
, "Name_score" AS "*Name_matched.Name_score"
139
, "Name_matched_author" AS "matchedScientificNameAuthorship"
140
, "Name_matched_url" AS "matchedScientificNameID"
141
, "Author_score" AS "*Name_matched.Author_score"
142
, "Family_score" AS "matchedFamilyConfidence_fraction"
143 9762 aaronmk
, COALESCE("Name_matched_accepted_family", "Accepted_name_family") AS "matchedFamily"
144 7831 aaronmk
, "Genus_matched" AS "matchedGenus"
145 7823 aaronmk
, "Genus_score" AS "matchedGenusConfidence_fraction"
146
, "Specific_epithet_matched" AS "matchedSpecificEpithet"
147
, "Specific_epithet_score" AS "matchedSpeciesConfidence_fraction"
148
, "Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet"
149
, "Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score"
150
, "Annotations" AS "identificationQualifier"
151
, "Unmatched_terms" AS "morphospeciesSuffix"
152 7833 aaronmk
, "Taxonomic_status" AS "taxonomicStatus"
153 7823 aaronmk
, "Accepted_name" AS "acceptedTaxonName"
154
, "Accepted_name_author" AS "acceptedScientificNameAuthorship"
155
, "Accepted_name_rank" AS "acceptedTaxonRank"
156
, "Accepted_name_url" AS "acceptedScientificNameID"
157 9762 aaronmk
, "Accepted_name_species" AS "*Name_matched.Accepted_name_species"
158
, "Accepted_name_family" AS "acceptedFamily"
159 7823 aaronmk
, "Selected" AS "*Name_matched.Selected"
160 7828 aaronmk
, "Source" AS "*Name_matched.Source"
161 7823 aaronmk
, "Warnings" AS "*Name_matched.Warnings"
162
, "Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid"
163
, "Accepted_scientific_name" AS "acceptedScientificName"
164
, "Max_score" AS "matchedTaxonConfidence_fraction"
165 9616 aaronmk
FROM tnrs
166
;
167 7823 aaronmk
168 9759 aaronmk
CREATE OR REPLACE VIEW "ValidMatchedTaxon" AS
169
SELECT *
170
FROM "MatchedTaxon"
171
WHERE score_ok("matchedTaxonConfidence_fraction")
172
;
173
174 7823 aaronmk
CREATE OR REPLACE VIEW "AcceptedTaxon" AS
175
SELECT
176
  "Time_submitted" AS "*Accepted_name.Time_submitted"
177
, "Name_submitted" AS "acceptedScientificName"
178
, "Genus_matched" AS "acceptedGenus"
179
, "Specific_epithet_matched" AS "acceptedSpecificEpithet"
180
, "Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet"
181
, "Annotations" AS "*Accepted_name.Annotations"
182
, "Taxonomic_status" AS "acceptedTaxonomicStatus"
183
, "Selected" AS "*Accepted_name.Selected"
184
, "Source" AS "*Accepted_name.Source"
185
, "Warnings" AS "*Accepted_name.Warnings"
186
, "Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid"
187 9760 aaronmk
FROM tnrs
188
;
189 7823 aaronmk
190
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
191
SELECT *
192 9758 aaronmk
FROM "ValidMatchedTaxon"
193 7823 aaronmk
NATURAL LEFT JOIN "AcceptedTaxon"
194
;