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 "Ecatalog_all".family
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_species_binomials; Type: VIEW; Schema: NY; Owner: -
72
--
73

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

    
79

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

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

    
88

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

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

    
98

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

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

    
107

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

    
112
CREATE VIEW _specimens_06_count_of_unique_verb_subsp_taxa_with_author AS
113
 SELECT count(DISTINCT "Ecatalog_all"."scientificName") AS taxon_names_with_author
114
   FROM "Ecatalog_all"
115
  WHERE ((("Ecatalog_all".genus IS NOT NULL) AND ("Ecatalog_all"."specificEpithet" IS NOT NULL)) AND ("Ecatalog_all".subspecies IS NOT NULL));
116

    
117

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

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

    
126

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

    
131
CREATE VIEW _specimens_07_list_of_verbatim_subspecific_taxa_with_author AS
132
 SELECT DISTINCT "Ecatalog_all"."scientificName" AS taxon_name_with_author
133
   FROM "Ecatalog_all"
134
  WHERE ("Ecatalog_all".subspecies IS NOT NULL);
135

    
136

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

    
141
COMMENT ON VIEW _specimens_07_list_of_verbatim_subspecific_taxa_with_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 "Ecatalog_all"."scientificName") AS taxon_names_with_author
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 "Ecatalog_all"."scientificName" AS taxon_name_with_author
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(DISTINCT ROW("Ecatalog_all"."decimalLatitude", "Ecatalog_all"."decimalLongitude")) AS count
257
           FROM "Ecatalog_all"
258
          WHERE (("Ecatalog_all"."decimalLatitude" IS NOT NULL) OR ("Ecatalog_all"."decimalLongitude" IS NOT NULL))) AS "allLatLongs", 
259
    ( SELECT count(DISTINCT ROW("Ecatalog_all"."decimalLatitude", "Ecatalog_all"."decimalLongitude")) AS count
260
           FROM "Ecatalog_all"
261
          WHERE (is_castable("Ecatalog_all"."decimalLatitude", NULL::double precision) AND is_castable("Ecatalog_all"."decimalLongitude", NULL::double precision))) AS "decimalLatLongs";
262

    
263

    
264
--
265
-- Name: VIEW _specimens_13_count_of_all_verbatim_and_decimal_lat_long; Type: COMMENT; Schema: NY; Owner: -
266
--
267

    
268
COMMENT ON VIEW _specimens_13_count_of_all_verbatim_and_decimal_lat_long IS '
269
Check: should return 1 row
270
';
271

    
272

    
273
--
274
-- Name: _specimens_13a_list_of_all_verbatim_lat_long; Type: VIEW; Schema: NY; Owner: -
275
--
276

    
277
CREATE VIEW _specimens_13a_list_of_all_verbatim_lat_long AS
278
 SELECT DISTINCT "Ecatalog_all"."decimalLatitude" AS "verbatimLatitude", 
279
    "Ecatalog_all"."decimalLongitude" AS "verbatimLongitude"
280
   FROM "Ecatalog_all"
281
  WHERE (("Ecatalog_all"."decimalLatitude" IS NOT NULL) OR ("Ecatalog_all"."decimalLongitude" IS NOT NULL));
282

    
283

    
284
--
285
-- Name: _specimens_13b_list_of_all_decimal_lat_long; Type: VIEW; Schema: NY; Owner: -
286
--
287

    
288
CREATE VIEW _specimens_13b_list_of_all_decimal_lat_long AS
289
 SELECT DISTINCT ("Ecatalog_all"."decimalLatitude")::double precision AS "decimalLatitude", 
290
    ("Ecatalog_all"."decimalLongitude")::double precision AS "decimalLongitude"
291
   FROM "Ecatalog_all"
292
  WHERE (is_castable("Ecatalog_all"."decimalLatitude", NULL::double precision) AND is_castable("Ecatalog_all"."decimalLongitude", NULL::double precision));
293

    
294

    
295
--
296
-- Name: _specimens_14_count_of_all_invalid_verbatim_lat_long; Type: VIEW; Schema: NY; Owner: -
297
--
298

    
299
CREATE VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long AS
300
 SELECT ( SELECT count(*) AS count
301
           FROM "Ecatalog_all"
302
          WHERE ((("Ecatalog_all"."decimalLatitude")::double precision > (90)::double precision) OR (("Ecatalog_all"."decimalLatitude")::double precision < ((-90))::double precision))) AS "badLats", 
303
    ( SELECT count(*) AS count
304
           FROM "Ecatalog_all"
305
          WHERE ((("Ecatalog_all"."decimalLongitude")::double precision > (180)::double precision) OR (("Ecatalog_all"."decimalLongitude")::double precision < ((-180))::double precision))) AS "badLongs";
306

    
307

    
308
--
309
-- Name: VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long; Type: COMMENT; Schema: NY; Owner: -
310
--
311

    
312
COMMENT ON VIEW _specimens_14_count_of_all_invalid_verbatim_lat_long IS '
313
Check: should return 1 row
314
';
315

    
316

    
317
--
318
-- Name: _specimens_15_list_distinct_locality_descriptions; Type: VIEW; Schema: NY; Owner: -
319
--
320

    
321
CREATE VIEW _specimens_15_list_distinct_locality_descriptions AS
322
 SELECT DISTINCT "Ecatalog_all".locality AS "localityDescription"
323
   FROM "Ecatalog_all"
324
  WHERE ("Ecatalog_all".locality IS NOT NULL);
325

    
326

    
327
--
328
-- Name: VIEW _specimens_15_list_distinct_locality_descriptions; Type: COMMENT; Schema: NY; Owner: -
329
--
330

    
331
COMMENT ON VIEW _specimens_15_list_distinct_locality_descriptions IS '
332
Check: should return 125592 records
333
';
334

    
335

    
336
--
337
-- Name: _specimens_16_list_distinct_specimen_descriptions; Type: VIEW; Schema: NY; Owner: -
338
--
339

    
340
CREATE VIEW _specimens_16_list_distinct_specimen_descriptions AS
341
 SELECT DISTINCT "Ecatalog_all"."specimenDescription"
342
   FROM "Ecatalog_all"
343
  WHERE ("Ecatalog_all"."specimenDescription" IS NOT NULL);
344

    
345

    
346
--
347
-- Name: VIEW _specimens_16_list_distinct_specimen_descriptions; Type: COMMENT; Schema: NY; Owner: -
348
--
349

    
350
COMMENT ON VIEW _specimens_16_list_distinct_specimen_descriptions IS '
351
Note: specimens descriptions in nybg extract is in column "specimenDescription"
352

    
353
Check: should return 158460 records
354
';
355

    
356

    
357
--
358
-- PostgreSQL database dump complete
359
--
360

    
(4-4/5)