summaryrefslogtreecommitdiffstats
path: root/contrib/earthdistance/sql/earthdistance.sql
blob: 41455612175ae192dba0fea22fb70e7fe35385cc (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
--
--  Test earthdistance extension
--
-- In this file we also do some testing of extension create/drop scenarios.
-- That's really exercising the core database's dependency logic, so ideally
-- we'd do it in the core regression tests, but we can't for lack of suitable
-- guaranteed-available extensions.  earthdistance is a good test case because
-- it has a dependency on the cube extension.
--

CREATE EXTENSION earthdistance;  -- fail, must install cube first
CREATE EXTENSION cube;
CREATE EXTENSION earthdistance;

--
-- The radius of the Earth we are using.
--

SELECT earth()::numeric(20,5);

--
-- Convert straight line distances to great circle distances.
--
SELECT (pi()*earth())::numeric(20,5);
SELECT sec_to_gc(0)::numeric(20,5);
SELECT sec_to_gc(2*earth())::numeric(20,5);
SELECT sec_to_gc(10*earth())::numeric(20,5);
SELECT sec_to_gc(-earth())::numeric(20,5);
SELECT sec_to_gc(1000)::numeric(20,5);
SELECT sec_to_gc(10000)::numeric(20,5);
SELECT sec_to_gc(100000)::numeric(20,5);
SELECT sec_to_gc(1000000)::numeric(20,5);

--
-- Convert great circle distances to straight line distances.
--

SELECT gc_to_sec(0)::numeric(20,5);
SELECT gc_to_sec(sec_to_gc(2*earth()))::numeric(20,5);
SELECT gc_to_sec(10*earth())::numeric(20,5);
SELECT gc_to_sec(pi()*earth())::numeric(20,5);
SELECT gc_to_sec(-1000)::numeric(20,5);
SELECT gc_to_sec(1000)::numeric(20,5);
SELECT gc_to_sec(10000)::numeric(20,5);
SELECT gc_to_sec(100000)::numeric(20,5);
SELECT gc_to_sec(1000000)::numeric(20,5);

--
-- Set coordinates using latitude and longitude.
-- Extract each coordinate separately so we can round them.
--

SELECT cube_ll_coord(ll_to_earth(0,0),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,0),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,0),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(360,360),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(360,360),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(360,360),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(180,180),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(180,180),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(180,180),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(180,360),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(180,360),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(180,360),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(-180,-360),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-180,-360),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-180,-360),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(0,180),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,180),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,180),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(0,-180),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,-180),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(0,-180),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(90,0),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(90,0),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(90,0),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(90,180),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(90,180),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(90,180),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(-90,0),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-90,0),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-90,0),3)::numeric(20,5);
SELECT cube_ll_coord(ll_to_earth(-90,180),1)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-90,180),2)::numeric(20,5),
 cube_ll_coord(ll_to_earth(-90,180),3)::numeric(20,5);

--
-- Test getting the latitude of a location.
--

SELECT latitude(ll_to_earth(0,0))::numeric(20,10);
SELECT latitude(ll_to_earth(45,0))::numeric(20,10);
SELECT latitude(ll_to_earth(90,0))::numeric(20,10);
SELECT latitude(ll_to_earth(-45,0))::numeric(20,10);
SELECT latitude(ll_to_earth(-90,0))::numeric(20,10);
SELECT latitude(ll_to_earth(0,90))::numeric(20,10);
SELECT latitude(ll_to_earth(45,90))::numeric(20,10);
SELECT latitude(ll_to_earth(90,90))::numeric(20,10);
SELECT latitude(ll_to_earth(-45,90))::numeric(20,10);
SELECT latitude(ll_to_earth(-90,90))::numeric(20,10);
SELECT latitude(ll_to_earth(0,180))::numeric(20,10);
SELECT latitude(ll_to_earth(45,180))::numeric(20,10);
SELECT latitude(ll_to_earth(90,180))::numeric(20,10);
SELECT latitude(ll_to_earth(-45,180))::numeric(20,10);
SELECT latitude(ll_to_earth(-90,180))::numeric(20,10);
SELECT latitude(ll_to_earth(0,-90))::numeric(20,10);
SELECT latitude(ll_to_earth(45,-90))::numeric(20,10);
SELECT latitude(ll_to_earth(90,-90))::numeric(20,10);
SELECT latitude(ll_to_earth(-45,-90))::numeric(20,10);
SELECT latitude(ll_to_earth(-90,-90))::numeric(20,10);

--
-- Test getting the longitude of a location.
--

SELECT longitude(ll_to_earth(0,0))::numeric(20,10);
SELECT longitude(ll_to_earth(45,0))::numeric(20,10);
SELECT longitude(ll_to_earth(90,0))::numeric(20,10);
SELECT longitude(ll_to_earth(-45,0))::numeric(20,10);
SELECT longitude(ll_to_earth(-90,0))::numeric(20,10);
SELECT longitude(ll_to_earth(0,90))::numeric(20,10);
SELECT longitude(ll_to_earth(45,90))::numeric(20,10);
SELECT longitude(ll_to_earth(90,90))::numeric(20,10);
SELECT longitude(ll_to_earth(-45,90))::numeric(20,10);
SELECT longitude(ll_to_earth(-90,90))::numeric(20,10);
SELECT longitude(ll_to_earth(0,180))::numeric(20,10);
SELECT longitude(ll_to_earth(45,180))::numeric(20,10);
SELECT longitude(ll_to_earth(90,180))::numeric(20,10);
SELECT longitude(ll_to_earth(-45,180))::numeric(20,10);
SELECT longitude(ll_to_earth(-90,180))::numeric(20,10);
SELECT longitude(ll_to_earth(0,-90))::numeric(20,10);
SELECT longitude(ll_to_earth(45,-90))::numeric(20,10);
SELECT longitude(ll_to_earth(90,-90))::numeric(20,10);
SELECT longitude(ll_to_earth(-45,-90))::numeric(20,10);
SELECT longitude(ll_to_earth(-90,-90))::numeric(20,10);

--
-- For the distance tests the following is some real life data.
--
-- Chicago has a latitude of 41.8 and a longitude of 87.6.
-- Albuquerque has a latitude of 35.1 and a longitude of 106.7.
-- (Note that latitude and longitude are specified differently
-- in the cube based functions than for the point based functions.)
--

--
-- Test getting the distance between two points using earth_distance.
--

SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(0,0))::numeric(20,5);
SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(0,180))::numeric(20,5);
SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(90,0))::numeric(20,5);
SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(0,90))::numeric(20,5);
SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(0,1))::numeric(20,5);
SELECT earth_distance(ll_to_earth(0,0),ll_to_earth(1,0))::numeric(20,5);
SELECT earth_distance(ll_to_earth(30,0),ll_to_earth(30,1))::numeric(20,5);
SELECT earth_distance(ll_to_earth(30,0),ll_to_earth(31,0))::numeric(20,5);
SELECT earth_distance(ll_to_earth(60,0),ll_to_earth(60,1))::numeric(20,5);
SELECT earth_distance(ll_to_earth(60,0),ll_to_earth(61,0))::numeric(20,5);
SELECT earth_distance(ll_to_earth(41.8,87.6),ll_to_earth(35.1,106.7))::numeric(20,5);
SELECT (earth_distance(ll_to_earth(41.8,87.6),ll_to_earth(35.1,106.7))*
      100./2.54/12./5280.)::numeric(20,5);

--
-- Test getting the distance between two points using geo_distance.
--

SELECT geo_distance('(0,0)'::point,'(0,0)'::point)::numeric(20,5);
SELECT geo_distance('(0,0)'::point,'(180,0)'::point)::numeric(20,5);
SELECT geo_distance('(0,0)'::point,'(0,90)'::point)::numeric(20,5);
SELECT geo_distance('(0,0)'::point,'(90,0)'::point)::numeric(20,5);
SELECT geo_distance('(0,0)'::point,'(1,0)'::point)::numeric(20,5);
SELECT geo_distance('(0,0)'::point,'(0,1)'::point)::numeric(20,5);
SELECT geo_distance('(0,30)'::point,'(1,30)'::point)::numeric(20,5);
SELECT geo_distance('(0,30)'::point,'(0,31)'::point)::numeric(20,5);
SELECT geo_distance('(0,60)'::point,'(1,60)'::point)::numeric(20,5);
SELECT geo_distance('(0,60)'::point,'(0,61)'::point)::numeric(20,5);
SELECT geo_distance('(87.6,41.8)'::point,'(106.7,35.1)'::point)::numeric(20,5);
SELECT (geo_distance('(87.6,41.8)'::point,'(106.7,35.1)'::point)*5280.*12.*2.54/100.)::numeric(20,5);

--
-- Test getting the distance between two points using the <@> operator.
--

SELECT ('(0,0)'::point <@> '(0,0)'::point)::numeric(20,5);
SELECT ('(0,0)'::point <@> '(180,0)'::point)::numeric(20,5);
SELECT ('(0,0)'::point <@> '(0,90)'::point)::numeric(20,5);
SELECT ('(0,0)'::point <@> '(90,0)'::point)::numeric(20,5);
SELECT ('(0,0)'::point <@> '(1,0)'::point)::numeric(20,5);
SELECT ('(0,0)'::point <@> '(0,1)'::point)::numeric(20,5);
SELECT ('(0,30)'::point <@> '(1,30)'::point)::numeric(20,5);
SELECT ('(0,30)'::point <@> '(0,31)'::point)::numeric(20,5);
SELECT ('(0,60)'::point <@> '(1,60)'::point)::numeric(20,5);
SELECT ('(0,60)'::point <@> '(0,61)'::point)::numeric(20,5);
SELECT ('(87.6,41.8)'::point <@> '(106.7,35.1)'::point)::numeric(20,5);
SELECT (('(87.6,41.8)'::point <@> '(106.7,35.1)'::point)*5280.*12.*2.54/100.)::numeric(20,5);

--
-- Test getting a bounding box around points.
--

SELECT cube_ll_coord(earth_box(ll_to_earth(0,0),112000),1)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),112000),2)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),112000),3)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),112000),1)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),112000),2)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),112000),3)::numeric(20,5);
SELECT cube_ll_coord(earth_box(ll_to_earth(0,0),pi()*earth()),1)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),pi()*earth()),2)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),pi()*earth()),3)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),pi()*earth()),1)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),pi()*earth()),2)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),pi()*earth()),3)::numeric(20,5);
SELECT cube_ll_coord(earth_box(ll_to_earth(0,0),10*earth()),1)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),10*earth()),2)::numeric(20,5),
       cube_ll_coord(earth_box(ll_to_earth(0,0),10*earth()),3)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),10*earth()),1)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),10*earth()),2)::numeric(20,5),
       cube_ur_coord(earth_box(ll_to_earth(0,0),10*earth()),3)::numeric(20,5);

--
-- Test for points that should be in bounding boxes.
--

SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,1))*1.00001) @>
       ll_to_earth(0,1);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.1))*1.00001) @>
       ll_to_earth(0,0.1);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.01))*1.00001) @>
       ll_to_earth(0,0.01);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.001))*1.00001) @>
       ll_to_earth(0,0.001);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.0001))*1.00001) @>
       ll_to_earth(0,0.0001);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0.0001,0.0001))*1.00001) @>
       ll_to_earth(0.0001,0.0001);
SELECT earth_box(ll_to_earth(45,45),
       earth_distance(ll_to_earth(45,45),ll_to_earth(45.0001,45.0001))*1.00001) @>
       ll_to_earth(45.0001,45.0001);
SELECT earth_box(ll_to_earth(90,180),
       earth_distance(ll_to_earth(90,180),ll_to_earth(90.0001,180.0001))*1.00001) @>
       ll_to_earth(90.0001,180.0001);

--
-- Test for points that shouldn't be in bounding boxes. Note that we need
-- to make points way outside, since some points close may be in the box
-- but further away than the distance we are testing.
--

SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,1))*.57735) @>
       ll_to_earth(0,1);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.1))*.57735) @>
       ll_to_earth(0,0.1);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.01))*.57735) @>
       ll_to_earth(0,0.01);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.001))*.57735) @>
       ll_to_earth(0,0.001);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0,0.0001))*.57735) @>
       ll_to_earth(0,0.0001);
SELECT earth_box(ll_to_earth(0,0),
       earth_distance(ll_to_earth(0,0),ll_to_earth(0.0001,0.0001))*.57735) @>
       ll_to_earth(0.0001,0.0001);
SELECT earth_box(ll_to_earth(45,45),
       earth_distance(ll_to_earth(45,45),ll_to_earth(45.0001,45.0001))*.57735) @>
       ll_to_earth(45.0001,45.0001);
SELECT earth_box(ll_to_earth(90,180),
       earth_distance(ll_to_earth(90,180),ll_to_earth(90.0001,180.0001))*.57735) @>
       ll_to_earth(90.0001,180.0001);

--
-- Test the recommended constraints.
--

SELECT cube_is_point(ll_to_earth(0,0));
SELECT cube_dim(ll_to_earth(0,0)) <= 3;
SELECT abs(cube_distance(ll_to_earth(0,0), '(0)'::cube) / earth() - 1) <
       '10e-12'::float8;
SELECT cube_is_point(ll_to_earth(30,60));
SELECT cube_dim(ll_to_earth(30,60)) <= 3;
SELECT abs(cube_distance(ll_to_earth(30,60), '(0)'::cube) / earth() - 1) <
       '10e-12'::float8;
SELECT cube_is_point(ll_to_earth(60,90));
SELECT cube_dim(ll_to_earth(60,90)) <= 3;
SELECT abs(cube_distance(ll_to_earth(60,90), '(0)'::cube) / earth() - 1) <
       '10e-12'::float8;
SELECT cube_is_point(ll_to_earth(-30,-90));
SELECT cube_dim(ll_to_earth(-30,-90)) <= 3;
SELECT abs(cube_distance(ll_to_earth(-30,-90), '(0)'::cube) / earth() - 1) <
       '10e-12'::float8;

--
-- Now we are going to test extension create/drop scenarios.
--

-- list what's installed
\dT

drop extension cube;  -- fail, earthdistance requires it

drop extension earthdistance;

drop type cube;  -- fail, extension cube requires it

-- list what's installed
\dT

create table foo (f1 cube, f2 int);

drop extension cube;  -- fail, foo.f1 requires it

drop table foo;

drop extension cube;

-- list what's installed
\dT
\df
\do

create schema c;

create extension cube with schema c;

-- list what's installed
\dT public.*
\df public.*
\do public.*
\dT c.*

create table foo (f1 c.cube, f2 int);

drop extension cube;  -- fail, foo.f1 requires it

drop schema c;  -- fail, cube requires it

drop extension cube cascade;

\d foo

-- list what's installed
\dT public.*
\df public.*
\do public.*
\dT c.*
\df c.*
\do c.*

drop schema c;