Project

General

Profile

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
SET search_path = "NY", pg_catalog;
13

    
14
--
15
-- Name: _specimens_01_count_of_total_records_specimens_in_source_db; Type: VIEW; Schema: NY; Owner: -
16
--
17

    
18
CREATE VIEW _specimens_01_count_of_total_records_specimens_in_source_db AS
19
 SELECT count(*) AS "totalSpecimenRecords"
20
   FROM "Ecatalog_all";
21

    
22

    
23
--
24
-- Name: VIEW _specimens_01_count_of_total_records_specimens_in_source_db; Type: COMMENT; Schema: NY; Owner: -
25
--
26

    
27
COMMENT ON VIEW _specimens_01_count_of_total_records_specimens_in_source_db IS '
28
Check: should return 1 row
29
';
30

    
31

    
32
--
33
-- Name: _specimens_02_count_of_unique_verbatim_families; Type: VIEW; Schema: NY; Owner: -
34
--
35

    
36
CREATE VIEW _specimens_02_count_of_unique_verbatim_families AS
37
 SELECT count(DISTINCT "Ecatalog_all".family) AS families
38
   FROM "Ecatalog_all"
39
  WHERE ("Ecatalog_all".family IS NOT NULL);
40

    
41

    
42
--
43
-- Name: VIEW _specimens_02_count_of_unique_verbatim_families; Type: COMMENT; Schema: NY; Owner: -
44
--
45

    
46
COMMENT ON VIEW _specimens_02_count_of_unique_verbatim_families IS '
47
Check: should return 1 row
48
';
49

    
50

    
51
--
52
-- Name: _specimens_03_list_of_verbatim_families; Type: VIEW; Schema: NY; Owner: -
53
--
54

    
55
CREATE VIEW _specimens_03_list_of_verbatim_families AS
56
 SELECT DISTINCT concat_ws(' '::text, "Ecatalog_all".genus, "Ecatalog_all"."specificEpithet") AS "specificEpithet"
57
   FROM "Ecatalog_all"
58
  WHERE (("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL));
59

    
60

    
61
--
62
-- Name: VIEW _specimens_03_list_of_verbatim_families; Type: COMMENT; Schema: NY; Owner: -
63
--
64

    
65
COMMENT ON VIEW _specimens_03_list_of_verbatim_families IS '
66
Check: should return same number of rows
67
';
68

    
69

    
70
--
71
-- Name: _specimens_04_count_of_unique_verbatim_species_without_author; Type: VIEW; Schema: NY; Owner: -
72
--
73

    
74
CREATE VIEW _specimens_04_count_of_unique_verbatim_species_without_author AS
75
 SELECT count(DISTINCT concat_ws(' '::text, "Ecatalog_all".genus, "Ecatalog_all"."specificEpithet")) AS subspecies
76
   FROM "Ecatalog_all"
77
  WHERE ((("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL)) AND ("Ecatalog_all".subspecies IS NOT NULL));
78

    
79

    
80
--
81
-- Name: VIEW _specimens_04_count_of_unique_verbatim_species_without_author; Type: COMMENT; Schema: NY; Owner: -
82
--
83

    
84
COMMENT ON VIEW _specimens_04_count_of_unique_verbatim_species_without_author IS '
85
Check: should return 1 row
86
';
87

    
88

    
89
--
90
-- Name: _specimens_05_list_of_verbatim_species_excluding_author; Type: VIEW; Schema: NY; Owner: -
91
--
92

    
93
CREATE VIEW _specimens_05_list_of_verbatim_species_excluding_author AS
94
 SELECT DISTINCT concat_ws(' '::text, "Ecatalog_all".genus, "Ecatalog_all"."specificEpithet") AS subspecies
95
   FROM "Ecatalog_all"
96
  WHERE ((("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL)) AND ("Ecatalog_all".subspecies IS NOT NULL));
97

    
98

    
99
--
100
-- Name: VIEW _specimens_05_list_of_verbatim_species_excluding_author; Type: COMMENT; Schema: NY; Owner: -
101
--
102

    
103
COMMENT ON VIEW _specimens_05_list_of_verbatim_species_excluding_author IS '
104
Check: should return 3335 rows
105
';
106

    
107

    
108
--
109
-- Name: _specimens_06_count_of_unique_verb_subsp_taxa_without_author; Type: VIEW; Schema: NY; Owner: -
110
--
111

    
112
CREATE VIEW _specimens_06_count_of_unique_verb_subsp_taxa_without_author AS
113
 SELECT count(DISTINCT concat_ws(' '::text, "Ecatalog_all".genus, "Ecatalog_all"."specificEpithet", "Ecatalog_all".subspecies)) AS "specificEpithet"
114
   FROM "Ecatalog_all"
115
  WHERE (("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL));
116

    
117

    
118
--
119
-- Name: VIEW _specimens_06_count_of_unique_verb_subsp_taxa_without_author; Type: COMMENT; Schema: NY; Owner: -
120
--
121

    
122
COMMENT ON VIEW _specimens_06_count_of_unique_verb_subsp_taxa_without_author IS '
123
Check: should return 1 row
124
';
125

    
126

    
127
--
128
-- Name: _specimens_07_list_of_verbatim_subspecific_taxa_without_author; Type: VIEW; Schema: NY; Owner: -
129
--
130

    
131
CREATE VIEW _specimens_07_list_of_verbatim_subspecific_taxa_without_author AS
132
 SELECT DISTINCT concat_ws(' '::text, "Ecatalog_all".genus, "Ecatalog_all"."specificEpithet") AS "specificEpithet"
133
   FROM "Ecatalog_all"
134
  WHERE (("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL));
135

    
136

    
137
--
138
-- Name: VIEW _specimens_07_list_of_verbatim_subspecific_taxa_without_author; Type: COMMENT; Schema: NY; Owner: -
139
--
140

    
141
COMMENT ON VIEW _specimens_07_list_of_verbatim_subspecific_taxa_without_author IS '
142
Check: should return 40145 rows
143
';
144

    
145

    
146
--
147
-- Name: _specimens_08_count_of_unique_verbatim_author_taxa_with_genus; Type: VIEW; Schema: NY; Owner: -
148
--
149

    
150
CREATE VIEW _specimens_08_count_of_unique_verbatim_author_taxa_with_genus AS
151
 SELECT count(DISTINCT btrim(concat_ws(' '::text, btrim(concat_ws(' '::text, "Ecatalog_all".genus, ifnull("Ecatalog_all"."specificEpithet", ''::text), ifnull("Ecatalog_all".subspecies, ''::text))), btrim(ifnull("Ecatalog_all"."scientificNameAuthorship", ''::text))))) AS "fullScientificNames"
152
   FROM "Ecatalog_all"
153
  WHERE ("Ecatalog_all".genus IS NOT NULL);
154

    
155

    
156
--
157
-- Name: VIEW _specimens_08_count_of_unique_verbatim_author_taxa_with_genus; Type: COMMENT; Schema: NY; Owner: -
158
--
159

    
160
COMMENT ON VIEW _specimens_08_count_of_unique_verbatim_author_taxa_with_genus IS '
161
Check: should return 1 row
162
';
163

    
164

    
165
--
166
-- Name: _specimens_09_list_of_unique_verbatim_author_taxa_with_genus; Type: VIEW; Schema: NY; Owner: -
167
--
168

    
169
CREATE VIEW _specimens_09_list_of_unique_verbatim_author_taxa_with_genus AS
170
 SELECT DISTINCT btrim(concat_ws(' '::text, btrim(concat_ws(' '::text, "Ecatalog_all".genus, ifnull("Ecatalog_all"."specificEpithet", ''::text), ifnull("Ecatalog_all".subspecies, ''::text))), btrim(ifnull("Ecatalog_all"."scientificNameAuthorship", ''::text)))) AS "fullScientificName"
171
   FROM "Ecatalog_all"
172
  WHERE ("Ecatalog_all".genus IS NOT NULL);
173

    
174

    
175
--
176
-- Name: VIEW _specimens_09_list_of_unique_verbatim_author_taxa_with_genus; Type: COMMENT; Schema: NY; Owner: -
177
--
178

    
179
COMMENT ON VIEW _specimens_09_list_of_unique_verbatim_author_taxa_with_genus IS '
180
Check: should return 45997 rows
181
';
182

    
183

    
184
--
185
-- Name: _specimens_10_count_number_of_records_by_institution; Type: VIEW; Schema: NY; Owner: -
186
--
187

    
188
CREATE VIEW _specimens_10_count_number_of_records_by_institution AS
189
 SELECT "Ecatalog_all".specimen_duplicate_institutions, 
190
    count(*) AS records
191
   FROM "Ecatalog_all"
192
  GROUP BY "Ecatalog_all".specimen_duplicate_institutions;
193

    
194

    
195
--
196
-- Name: VIEW _specimens_10_count_number_of_records_by_institution; Type: COMMENT; Schema: NY; Owner: -
197
--
198

    
199
COMMENT ON VIEW _specimens_10_count_number_of_records_by_institution IS '
200
Note: Majority should be from ''NY''; these are standard herbarium acronyms
201

    
202
Check: should return 6 rows
203
';
204

    
205

    
206
--
207
-- Name: _specimens_11_list_of_three_standard_political_divisions; Type: VIEW; Schema: NY; Owner: -
208
--
209

    
210
CREATE VIEW _specimens_11_list_of_three_standard_political_divisions AS
211
 SELECT DISTINCT "Ecatalog_all".country, 
212
    "Ecatalog_all"."stateProvince", 
213
    "Ecatalog_all".county
214
   FROM "Ecatalog_all";
215

    
216

    
217
--
218
-- Name: VIEW _specimens_11_list_of_three_standard_political_divisions; Type: COMMENT; Schema: NY; Owner: -
219
--
220

    
221
COMMENT ON VIEW _specimens_11_list_of_three_standard_political_divisions IS '
222
Note: character set issues may cause mis-matches. This query is a good way to reveal character set issues, either in source db or in BIEN
223

    
224
Check: should return 5232 rows
225
';
226

    
227

    
228
--
229
-- Name: _specimens_12_distinct_collector_name_collect_num_date_w_count; Type: VIEW; Schema: NY; Owner: -
230
--
231

    
232
CREATE VIEW _specimens_12_distinct_collector_name_collect_num_date_w_count AS
233
 SELECT ifnull("Ecatalog_all"."recordedBy", ''::text) AS "collectorName", 
234
    ifnull("Ecatalog_all"."collectorNumber", ''::text) AS "collectionNumber", 
235
    concat_ws('-'::text, "Ecatalog_all"."yearCollected", "Ecatalog_all"."monthCollected", "Ecatalog_all"."dayCollected") AS "dateCollected", 
236
    count(*) AS "specimenRecords"
237
   FROM "Ecatalog_all"
238
  GROUP BY "Ecatalog_all"."recordedBy", "Ecatalog_all"."collectorNumber", concat_ws('-'::text, "Ecatalog_all"."yearCollected", "Ecatalog_all"."monthCollected", "Ecatalog_all"."dayCollected")
239
  ORDER BY "Ecatalog_all"."recordedBy", "Ecatalog_all"."collectorNumber", concat_ws('-'::text, "Ecatalog_all"."yearCollected", "Ecatalog_all"."monthCollected", "Ecatalog_all"."dayCollected");
240

    
241

    
242
--
243
-- Name: VIEW _specimens_12_distinct_collector_name_collect_num_date_w_count; Type: COMMENT; Schema: NY; Owner: -
244
--
245

    
246
COMMENT ON VIEW _specimens_12_distinct_collector_name_collect_num_date_w_count IS '
247
Check: should return 309396 rows
248
';
249

    
250

    
251
--
252
-- Name: _specimens_13_count_of_all_verbatim_and_decimal_lat_long; Type: VIEW; Schema: NY; Owner: -
253
--
254

    
255
CREATE VIEW _specimens_13_count_of_all_verbatim_and_decimal_lat_long AS
256
 SELECT ( SELECT count(*) AS count
257
           FROM "Ecatalog_all"
258
          WHERE ("Ecatalog_all"."decimalLatitude" IS NOT NULL)) AS "allLats", 
259
    ( SELECT count(*) AS count
260
           FROM "Ecatalog_all"
261
          WHERE ("Ecatalog_all"."decimalLatitude" ~ '^(-|\\+){0,1}([0-9]+\\.[0-9]*|[0-9]*\\.[0-9]+|[0-9]+)$'::text)) AS "decimalLats", 
262
    ( SELECT count(*) AS count
263
           FROM "Ecatalog_all"
264
          WHERE ("Ecatalog_all"."decimalLongitude" IS NOT NULL)) AS "allLongs", 
265
    ( SELECT count(*) AS count
266
           FROM "Ecatalog_all"
267
          WHERE ("Ecatalog_all"."decimalLongitude" ~ '^(-|\\+){0,1}([0-9]+\\.[0-9]*|[0-9]*\\.[0-9]+|[0-9]+)$'::text)) AS "decimalLongs";
268

    
269

    
270
--
271
-- Name: VIEW _specimens_13_count_of_all_verbatim_and_decimal_lat_long; Type: COMMENT; Schema: NY; Owner: -
272
--
273

    
274
COMMENT ON VIEW _specimens_13_count_of_all_verbatim_and_decimal_lat_long IS '
275
Check: should return 1 row
276
';
277

    
278

    
279
--
280
-- Name: _specimens_14_count_of_all_invalid_verbatim_lat_long; Type: VIEW; Schema: NY; Owner: -
281
--
282

    
283
CREATE VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long AS
284
 SELECT ( SELECT count(*) AS count
285
           FROM "Ecatalog_all"
286
          WHERE ((("Ecatalog_all"."decimalLatitude")::double precision > (90)::double precision) OR (("Ecatalog_all"."decimalLatitude")::double precision < ((-90))::double precision))) AS "badLats", 
287
    ( SELECT count(*) AS count
288
           FROM "Ecatalog_all"
289
          WHERE ((("Ecatalog_all"."decimalLongitude")::double precision > (180)::double precision) OR (("Ecatalog_all"."decimalLongitude")::double precision < ((-180))::double precision))) AS "badLongs";
290

    
291

    
292
--
293
-- Name: VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long; Type: COMMENT; Schema: NY; Owner: -
294
--
295

    
296
COMMENT ON VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long IS '
297
Check: should return 1 row
298
';
299

    
300

    
301
--
302
-- Name: _specimens_15_list_distinct_locality_descriptions; Type: VIEW; Schema: NY; Owner: -
303
--
304

    
305
CREATE VIEW _specimens_15_list_distinct_locality_descriptions AS
306
 SELECT DISTINCT "Ecatalog_all".locality__main AS "localityDescription"
307
   FROM "Ecatalog_all"
308
  WHERE ("Ecatalog_all".locality__main IS NOT NULL);
309

    
310

    
311
--
312
-- Name: VIEW _specimens_15_list_distinct_locality_descriptions; Type: COMMENT; Schema: NY; Owner: -
313
--
314

    
315
COMMENT ON VIEW _specimens_15_list_distinct_locality_descriptions IS '
316
Check: should return 125592 records
317
';
318

    
319

    
320
--
321
-- Name: _specimens_16_list_distinct_specimen_descriptions; Type: VIEW; Schema: NY; Owner: -
322
--
323

    
324
CREATE VIEW _specimens_16_list_distinct_specimen_descriptions AS
325
 SELECT "Ecatalog_all"."specimenDescription"
326
   FROM "Ecatalog_all"
327
  WHERE ("Ecatalog_all"."specimenDescription" IS NOT NULL);
328

    
329

    
330
--
331
-- Name: VIEW _specimens_16_list_distinct_specimen_descriptions; Type: COMMENT; Schema: NY; Owner: -
332
--
333

    
334
COMMENT ON VIEW _specimens_16_list_distinct_specimen_descriptions IS '
335
Note: specimens descriptions in nybg extract is in column "specimenDescription"
336

    
337
Check: should return 158460 records
338
';
339

    
340

    
341
--
342
-- PostgreSQL database dump complete
343
--
344

    
(11-11/12)