aboutsummaryrefslogtreecommitdiff
path: root/contrib/cube/sql/cube.sql
blob: 70feb8a217ab5106a5917137bd788af2ae624646 (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
--
--  Test cube datatype
--

--
-- first, define the datatype.  Turn off echoing so that expected file
-- does not depend on contents of cube.sql.
--
\set ECHO none
\i cube.sql
\set ECHO all

--
-- testing the input and output functions
--

-- Any number (a one-dimensional point)
SELECT '1'::cube AS cube;
SELECT '-1'::cube AS cube;
SELECT '1.'::cube AS cube;
SELECT '-1.'::cube AS cube;
SELECT '.1'::cube AS cube;
SELECT '-.1'::cube AS cube;
SELECT '1.0'::cube AS cube;
SELECT '-1.0'::cube AS cube;
SELECT '1e7'::cube AS cube;
SELECT '-1e7'::cube AS cube;
SELECT '1.0e7'::cube AS cube;
SELECT '-1.0e7'::cube AS cube;
SELECT '1e+7'::cube AS cube;
SELECT '-1e+7'::cube AS cube;
SELECT '1.0e+7'::cube AS cube;
SELECT '-1.0e+7'::cube AS cube;
SELECT '1e-7'::cube AS cube;
SELECT '-1e-7'::cube AS cube;
SELECT '1.0e-7'::cube AS cube;
SELECT '-1.0e-7'::cube AS cube;
SELECT '1e700'::cube AS cube;
SELECT '-1e700'::cube AS cube;
SELECT '1e-700'::cube AS cube;
SELECT '-1e-700'::cube AS cube;

-- simple lists (points)
SELECT '1,2'::cube AS cube;
SELECT '(1,2)'::cube AS cube;
SELECT '1,2,3,4,5'::cube AS cube;
SELECT '(1,2,3,4,5)'::cube AS cube;

-- double lists (cubes)
SELECT '(0),(0)'::cube AS cube;
SELECT '(0),(1)'::cube AS cube;
SELECT '[(0),(0)]'::cube AS cube;
SELECT '[(0),(1)]'::cube AS cube;
SELECT '(0,0,0,0),(0,0,0,0)'::cube AS cube;
SELECT '(0,0,0,0),(1,0,0,0)'::cube AS cube;
SELECT '[(0,0,0,0),(0,0,0,0)]'::cube AS cube;
SELECT '[(0,0,0,0),(1,0,0,0)]'::cube AS cube;

-- invalid input: parse errors
SELECT ''::cube AS cube;
SELECT 'ABC'::cube AS cube;
SELECT '()'::cube AS cube;
SELECT '[]'::cube AS cube;
SELECT '[()]'::cube AS cube;
SELECT '[(1)]'::cube AS cube;
SELECT '[(1),]'::cube AS cube;
SELECT '[(1),2]'::cube AS cube;
SELECT '[(1),(2),(3)]'::cube AS cube;
SELECT '1,'::cube AS cube;
SELECT '1,2,'::cube AS cube;
SELECT '1,,2'::cube AS cube;
SELECT '(1,)'::cube AS cube;
SELECT '(1,2,)'::cube AS cube;
SELECT '(1,,2)'::cube AS cube;

-- invalid input: semantic errors and trailing garbage
SELECT '[(1),(2)],'::cube AS cube; -- 0
SELECT '[(1,2,3),(2,3)]'::cube AS cube; -- 1
SELECT '[(1,2),(1,2,3)]'::cube AS cube; -- 1
SELECT '(1),(2),'::cube AS cube; -- 2
SELECT '(1,2,3),(2,3)'::cube AS cube; -- 3
SELECT '(1,2),(1,2,3)'::cube AS cube; -- 3
SELECT '(1,2,3)ab'::cube AS cube; -- 4
SELECT '(1,2,3)a'::cube AS cube; -- 5
SELECT '(1,2)('::cube AS cube; -- 5
SELECT '1,2ab'::cube AS cube; -- 6
SELECT '1 e7'::cube AS cube; -- 6
SELECT '1,2a'::cube AS cube; -- 7
SELECT '1..2'::cube AS cube; -- 7

--
-- testing the  operators
--

-- equality/inequality:
--
SELECT '24, 33.20'::cube    =  '24, 33.20'::cube AS bool;
SELECT '24, 33.20'::cube    != '24, 33.20'::cube AS bool;
SELECT '24, 33.20'::cube    =  '24, 33.21'::cube AS bool;
SELECT '24, 33.20'::cube    != '24, 33.21'::cube AS bool;
SELECT '(2,0),(3,1)'::cube  =  '(2,0,0,0,0),(3,1,0,0,0)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube  =  '(2,0,0,0,0),(3,1,0,0,1)'::cube AS bool;

-- "lower than" / "greater than"
-- (these operators are not useful for anything but ordering)
--
SELECT '1'::cube   > '2'::cube AS bool;
SELECT '1'::cube   < '2'::cube AS bool;
SELECT '1,1'::cube > '1,2'::cube AS bool;
SELECT '1,1'::cube < '1,2'::cube AS bool;

SELECT '(2,0),(3,1)'::cube             > '(2,0,0,0,0),(3,1,0,0,1)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube             < '(2,0,0,0,0),(3,1,0,0,1)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube             > '(2,0,0,0,1),(3,1,0,0,0)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube             < '(2,0,0,0,1),(3,1,0,0,0)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube             > '(2,0,0,0,0),(3,1,0,0,0)'::cube AS bool;
SELECT '(2,0),(3,1)'::cube             < '(2,0,0,0,0),(3,1,0,0,0)'::cube AS bool;
SELECT '(2,0,0,0,0),(3,1,0,0,1)'::cube > '(2,0),(3,1)'::cube AS bool;
SELECT '(2,0,0,0,0),(3,1,0,0,1)'::cube < '(2,0),(3,1)'::cube AS bool;
SELECT '(2,0,0,0,1),(3,1,0,0,0)'::cube > '(2,0),(3,1)'::cube AS bool;
SELECT '(2,0,0,0,1),(3,1,0,0,0)'::cube < '(2,0),(3,1)'::cube AS bool;
SELECT '(2,0,0,0,0),(3,1,0,0,0)'::cube > '(2,0),(3,1)'::cube AS bool;
SELECT '(2,0,0,0,0),(3,1,0,0,0)'::cube < '(2,0),(3,1)'::cube AS bool;


-- "overlap"
--
SELECT '1'::cube && '1'::cube AS bool;
SELECT '1'::cube && '2'::cube AS bool;

SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '0'::cube AS bool;
SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '1'::cube AS bool;
SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '1,1,1'::cube AS bool;
SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '[(1,1,1),(2,2,2)]'::cube AS bool;
SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '[(1,1),(2,2)]'::cube AS bool;
SELECT '[(-1,-1,-1),(1,1,1)]'::cube && '[(2,1,1),(2,2,2)]'::cube AS bool;

-- "overlap on the left" / "overlap on the right"
-- (these operators are not useful at all but R-tree seems to be
-- sensitive to their presence)
--
SELECT '1'::cube &< '0'::cube AS bool;
SELECT '1'::cube &< '1'::cube AS bool;
SELECT '1'::cube &< '2'::cube AS bool;

SELECT '(0),(1)'::cube &< '0'::cube AS bool;
SELECT '(0),(1)'::cube &< '1'::cube AS bool;
SELECT '(0),(1)'::cube &< '(0),(0.5)'::cube AS bool;
SELECT '(0),(1)'::cube &< '(0),(1)'::cube AS bool;
SELECT '(0),(1)'::cube &< '(0),(2)'::cube AS bool;
SELECT '(0),(1)'::cube &< '(1),(2)'::cube AS bool;
SELECT '(0),(1)'::cube &< '(2),(3)'::cube AS bool;

SELECT '0'::cube &> '1'::cube AS bool;
SELECT '1'::cube &> '1'::cube AS bool;
SELECT '2'::cube &> '1'::cube AS bool;

SELECT '0'::cube        &> '(0),(1)'::cube AS bool;
SELECT '1'::cube        &> '(0),(1)'::cube AS bool;
SELECT '(0),(0.5)'      &> '(0),(1)'::cube AS bool;
SELECT '(0),(1)'::cube  &> '(0),(1)'::cube AS bool;
SELECT '(0),(2)'::cube  &> '(0),(1)'::cube AS bool;
SELECT '(1),(2)'::cube  &> '(0),(1)'::cube AS bool;
SELECT '(2),(3)'::cube  &> '(0),(1)'::cube AS bool;


-- "left" / "right"
-- (these operators are not useful but for 1-D or 2-D cubes, but R-tree
-- seems to want them defined)
--
SELECT '1'::cube << '0'::cube AS bool;
SELECT '1'::cube << '1'::cube AS bool;
SELECT '1'::cube << '2'::cube AS bool;

SELECT '(0),(1)'::cube << '0'::cube AS bool;
SELECT '(0),(1)'::cube << '1'::cube AS bool;
SELECT '(0),(1)'::cube << '(0),(0.5)'::cube AS bool;
SELECT '(0),(1)'::cube << '(0),(1)'::cube AS bool;
SELECT '(0),(1)'::cube << '(0),(2)'::cube AS bool;
SELECT '(0),(1)'::cube << '(1),(2)'::cube AS bool;
SELECT '(0),(1)'::cube << '(2),(3)'::cube AS bool;

SELECT '0'::cube >> '1'::cube AS bool;
SELECT '1'::cube >> '1'::cube AS bool;
SELECT '2'::cube >> '1'::cube AS bool;

SELECT '0'::cube        >> '(0),(1)'::cube AS bool;
SELECT '1'::cube        >> '(0),(1)'::cube AS bool;
SELECT '(0),(0.5)'      >> '(0),(1)'::cube AS bool;
SELECT '(0),(1)'::cube  >> '(0),(1)'::cube AS bool;
SELECT '(0),(2)'::cube  >> '(0),(1)'::cube AS bool;
SELECT '(1),(2)'::cube  >> '(0),(1)'::cube AS bool;
SELECT '(2),(3)'::cube  >> '(0),(1)'::cube AS bool;


-- "contained in" (the left operand is the cube entirely enclosed by
-- the right operand):
--
SELECT '0'::cube                 ~ '0'::cube                        AS bool;
SELECT '0,0,0'::cube             ~ '0,0,0'::cube                    AS bool;
SELECT '0,0'::cube               ~ '0,0,1'::cube                    AS bool;
SELECT '0,0,0'::cube             ~ '0,0,1'::cube                    AS bool;
SELECT '1,0,0'::cube             ~ '0,0,1'::cube                    AS bool;
SELECT '(1,0,0),(0,0,1)'::cube   ~ '(1,0,0),(0,0,1)'::cube          AS bool;
SELECT '(1,0,0),(0,0,1)'::cube   ~ '(-1,-1,-1),(1,1,1)'::cube       AS bool;
SELECT '(1,0,0),(0,0,1)'::cube   ~ '(-1,-1,-1,-1),(1,1,1,1)'::cube  AS bool;
SELECT '0'::cube                 ~ '(-1),(1)'::cube                 AS bool;
SELECT '1'::cube                 ~ '(-1),(1)'::cube                 AS bool;
SELECT '-1'::cube                ~ '(-1),(1)'::cube                 AS bool;
SELECT '(-1),(1)'::cube          ~ '(-1),(1)'::cube                 AS bool;
SELECT '(-1),(1)'::cube          ~ '(-1,-1),(1,1)'::cube            AS bool;
SELECT '(-2),(1)'::cube          ~ '(-1),(1)'::cube                 AS bool;
SELECT '(-2),(1)'::cube          ~ '(-1,-1),(1,1)'::cube            AS bool;


-- "contains" (the left operand is the cube that entirely encloses the
-- right operand)
--
SELECT '0'::cube                        @ '0'::cube                 AS bool;
SELECT '0,0,0'::cube                    @ '0,0,0'::cube             AS bool;
SELECT '0,0,1'::cube                    @ '0,0'::cube               AS bool;
SELECT '0,0,1'::cube                    @ '0,0,0'::cube             AS bool;
SELECT '0,0,1'::cube                    @ '1,0,0'::cube             AS bool;
SELECT '(1,0,0),(0,0,1)'::cube          @ '(1,0,0),(0,0,1)'::cube   AS bool;
SELECT '(-1,-1,-1),(1,1,1)'::cube       @ '(1,0,0),(0,0,1)'::cube   AS bool;
SELECT '(-1,-1,-1,-1),(1,1,1,1)'::cube  @ '(1,0,0),(0,0,1)'::cube   AS bool;
SELECT '(-1),(1)'::cube                 @ '0'::cube                 AS bool;
SELECT '(-1),(1)'::cube                 @ '1'::cube                 AS bool;
SELECT '(-1),(1)'::cube                 @ '-1'::cube                AS bool;
SELECT '(-1),(1)'::cube                 @ '(-1),(1)'::cube          AS bool;
SELECT '(-1,-1),(1,1)'::cube            @ '(-1),(1)'::cube          AS bool;
SELECT '(-1),(1)'::cube                 @ '(-2),(1)'::cube          AS bool;
SELECT '(-1,-1),(1,1)'::cube            @ '(-2),(1)'::cube          AS bool;


-- Load some example data and build the index
-- 
CREATE TABLE test_cube (c cube);

\copy test_cube from 'data/test_cube.data'

CREATE INDEX test_cube_ix ON test_cube USING gist (c);
SELECT * FROM test_cube	WHERE c && '(3000,1000),(0,0)';

-- Test sorting 
SELECT * FROM test_cube	WHERE c && '(3000,1000),(0,0)' GROUP BY c;