Project

General

Profile

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
  "Max_score" double precision,
42
  CONSTRAINT tnrs_pkey PRIMARY KEY ("Name_submitted" )
43
)
44
WITH (
45
  OIDS=FALSE
46
);
47

    
48
CREATE OR REPLACE FUNCTION tnrs_populate_derived_fields()
49
  RETURNS trigger AS
50
$BODY$
51
BEGIN
52
    new."Accepted_scientific_name" = NULLIF(array_to_string(ARRAY[
53
        NULLIF(NULLIF(new."Accepted_name_family", 'Unknown'), new."Accepted_name")
54
        , new."Accepted_name"
55
        , new."Accepted_name_author"
56
    ], ' '), '');
57
    new."Max_score" = GREATEST(
58
          new."Overall_score"::double precision
59
        , new."Family_score"::double precision
60
        , new."Genus_score"::double precision
61
        , new."Specific_epithet_score"::double precision
62
    );
63
    
64
    RETURN new;
65
END;
66
$BODY$
67
  LANGUAGE plpgsql VOLATILE
68
  COST 100;
69

    
70
CREATE TRIGGER tnrs_populate_derived_fields
71
  BEFORE INSERT OR UPDATE
72
  ON tnrs
73
  FOR EACH ROW
74
  EXECUTE PROCEDURE tnrs_populate_derived_fields();
75

    
76

    
77
CREATE OR REPLACE VIEW "MatchedTaxon" AS
78
SELECT
79
  "Time_submitted" AS "*Name_matched.Time_submitted"
80
, "Name_matched" AS "concatenatedScientificName"
81
, "Name_matched_rank" AS "matchedTaxonRank"
82
, "Name_score" AS "*Name_matched.Name_score"
83
, "Name_matched_author" AS "matchedScientificNameAuthorship"
84
, "Name_matched_url" AS "matchedScientificNameID"
85
, "Author_score" AS "*Name_matched.Author_score"
86
, "Family_score" AS "matchedFamilyConfidence_fraction"
87
, "Name_matched_accepted_family" AS family
88
, "Genus_matched" AS genus
89
, "Genus_score" AS "matchedGenusConfidence_fraction"
90
, "Specific_epithet_matched" AS "matchedSpecificEpithet"
91
, "Specific_epithet_score" AS "matchedSpeciesConfidence_fraction"
92
, "Infraspecific_epithet_matched" AS "matchedInfraspecificEpithet"
93
, "Infraspecific_epithet_score" AS "*Name_matched.Infraspecific_epithet_score"
94
, "Annotations" AS "identificationQualifier"
95
, "Unmatched_terms" AS "morphospeciesSuffix"
96
, "Taxonomic_status" AS "taxonomicStatus"
97
, "Accepted_name" AS "acceptedTaxonName"
98
, "Accepted_name_author" AS "acceptedScientificNameAuthorship"
99
, "Accepted_name_rank" AS "acceptedTaxonRank"
100
, "Accepted_name_url" AS "acceptedScientificNameID"
101
, "Accepted_name_species" AS "*Name_matched.Accepted_name_species"
102
, "Accepted_name_family" AS "acceptedFamily"
103
, "Selected" AS "*Name_matched.Selected"
104
, "Source" AS source
105
, "Warnings" AS "*Name_matched.Warnings"
106
, "Accepted_name_lsid" AS "*Name_matched.Accepted_name_lsid"
107
, "Accepted_scientific_name" AS "acceptedScientificName"
108
, "Max_score" AS "matchedTaxonConfidence_fraction"
109
FROM tnrs;
110

    
111
CREATE OR REPLACE VIEW "AcceptedTaxon" AS
112
SELECT
113
  "Time_submitted" AS "*Accepted_name.Time_submitted"
114
, "Name_submitted" AS "acceptedScientificName"
115
, "Genus_matched" AS "acceptedGenus"
116
, "Specific_epithet_matched" AS "acceptedSpecificEpithet"
117
, "Infraspecific_epithet_matched" AS "acceptedInfraspecificEpithet"
118
, "Annotations" AS "*Accepted_name.Annotations"
119
, "Taxonomic_status" AS "acceptedTaxonomicStatus"
120
, "Selected" AS "*Accepted_name.Selected"
121
, "Source" AS "*Accepted_name.Source"
122
, "Warnings" AS "*Accepted_name.Warnings"
123
, "Accepted_name_lsid" AS "*Accepted_name.Accepted_name_lsid"
124
FROM tnrs;
125

    
126
CREATE OR REPLACE VIEW "ScrubbedTaxon" AS
127
SELECT *
128
FROM "MatchedTaxon"
129
NATURAL LEFT JOIN "AcceptedTaxon"
130
;
(3-3/3)