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
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
-- Create the user-defined type for the 1-D integer arrays (_int4)
--
BEGIN TRANSACTION;
-- Query type
CREATE FUNCTION bqarr_in(opaque)
RETURNS opaque
AS 'MODULE_PATHNAME'
LANGUAGE 'c' with (isstrict);
CREATE FUNCTION bqarr_out(opaque)
RETURNS opaque
AS 'MODULE_PATHNAME'
LANGUAGE 'c' with (isstrict);
CREATE TYPE query_int (
internallength = -1,
input = bqarr_in,
output = bqarr_out
);
--only for debug
CREATE FUNCTION querytree(query_int)
RETURNS text
AS 'MODULE_PATHNAME'
LANGUAGE 'c' with (isstrict);
CREATE FUNCTION boolop(_int4, query_int) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION boolop(_int4, query_int) IS 'boolean operation with array';
CREATE FUNCTION rboolop(query_int, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION rboolop(query_int, _int4) IS 'boolean operation with array';
CREATE OPERATOR @@ (
LEFTARG = _int4, RIGHTARG = query_int, PROCEDURE = boolop,
COMMUTATOR = '~~', RESTRICT = contsel, JOIN = contjoinsel
);
CREATE OPERATOR ~~ (
LEFTARG = query_int, RIGHTARG = _int4, PROCEDURE = rboolop,
COMMUTATOR = '@@', RESTRICT = contsel, JOIN = contjoinsel
);
--
-- External C-functions for R-tree methods
--
-- Comparison methods
CREATE FUNCTION _int_contains(_int4, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION _int_contains(_int4, _int4) IS 'contains';
CREATE FUNCTION _int_contained(_int4, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION _int_contained(_int4, _int4) IS 'contained in';
CREATE FUNCTION _int_overlap(_int4, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION _int_overlap(_int4, _int4) IS 'overlaps';
CREATE FUNCTION _int_same(_int4, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION _int_same(_int4, _int4) IS 'same as';
CREATE FUNCTION _int_different(_int4, _int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
COMMENT ON FUNCTION _int_different(_int4, _int4) IS 'different';
-- support routines for indexing
CREATE FUNCTION _int_union(_int4, _int4) RETURNS _int4
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
CREATE FUNCTION _int_inter(_int4, _int4) RETURNS _int4
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
--
-- OPERATORS
--
CREATE OPERATOR && (
LEFTARG = _int4, RIGHTARG = _int4, PROCEDURE = _int_overlap,
COMMUTATOR = '&&',
RESTRICT = contsel, JOIN = contjoinsel
);
--CREATE OPERATOR = (
-- LEFTARG = _int4, RIGHTARG = _int4, PROCEDURE = _int_same,
-- COMMUTATOR = '=', NEGATOR = '<>',
-- RESTRICT = eqsel, JOIN = eqjoinsel,
-- SORT1 = '<', SORT2 = '<'
--);
CREATE OPERATOR <> (
LEFTARG = _int4, RIGHTARG = _int4, PROCEDURE = _int_different,
COMMUTATOR = '<>', NEGATOR = '=',
RESTRICT = neqsel, JOIN = neqjoinsel
);
CREATE OPERATOR @ (
LEFTARG = _int4, RIGHTARG = _int4, PROCEDURE = _int_contains,
COMMUTATOR = '~', RESTRICT = contsel, JOIN = contjoinsel
);
CREATE OPERATOR ~ (
LEFTARG = _int4, RIGHTARG = _int4, PROCEDURE = _int_contained,
COMMUTATOR = '@', RESTRICT = contsel, JOIN = contjoinsel
);
-- define the GiST support methods
CREATE FUNCTION g_int_consistent(opaque,_int4,int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_int_compress(opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_int_decompress(opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_int_penalty(opaque,opaque,opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
CREATE FUNCTION g_int_picksplit(opaque, opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_int_union(bytea, opaque) RETURNS _int4
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_int_same(_int4, _int4, opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
-- register the default opclass for indexing
INSERT INTO pg_opclass (opcamid, opcname, opcnamespace, opcowner, opcintype, opcdefault, opckeytype)
VALUES (
(SELECT oid FROM pg_am WHERE amname = 'gist'),
'gist__int_ops',
(SELECT oid FROM pg_namespace WHERE nspname = 'pg_catalog'),
1, -- UID of superuser is hardwired to 1 as of PG 7.3
(SELECT oid FROM pg_type WHERE typname = '_int4'),
true,
0);
-- get the comparators for _intments and store them in a tmp table
SELECT o.oid AS opoid, o.oprname
INTO TEMP TABLE _int_ops_tmp
FROM pg_operator o, pg_type t, pg_type tq
WHERE o.oprleft = t.oid and ( o.oprright = t.oid or o.oprright=tq.oid )
and t.typname = '_int4'
and tq.typname='query_int';
-- make sure we have the right operators
-- SELECT * from _int_ops_tmp;
-- using the tmp table, generate the amop entries
-- _int_overlap
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 3, false, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and c.oprname = '&&';
-- _int_same
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 6, false, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and c.oprname = '=';
-- _int_contains
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 7, false, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and c.oprname = '@';
-- _int_contained
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 8, false, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and c.oprname = '~';
--boolean search
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 20, false, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and c.oprname = '@@';
DROP TABLE _int_ops_tmp;
-- add the entries to amproc for the support methods
-- note the amprocnum numbers associated with each are specific!
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 1, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_consistent';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 2, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_union';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 3, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_compress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 4, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_decompress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 5, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_penalty';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 6, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_picksplit';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 7, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__int_ops'
and proname = 'g_int_same';
---------------------------------------------
-- intbig
---------------------------------------------
-- define the GiST support methods
CREATE FUNCTION g_intbig_consistent(opaque,_int4,int4) RETURNS bool
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_intbig_compress(opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_intbig_decompress(opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_intbig_penalty(opaque,opaque,opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c' with (isstrict);
CREATE FUNCTION g_intbig_picksplit(opaque, opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_intbig_union(bytea, opaque) RETURNS _int4
AS 'MODULE_PATHNAME' LANGUAGE 'c';
CREATE FUNCTION g_intbig_same(_int4, _int4, opaque) RETURNS opaque
AS 'MODULE_PATHNAME' LANGUAGE 'c';
-- register the opclass for indexing (not as default)
INSERT INTO pg_opclass (opcamid, opcname, opcnamespace, opcowner, opcintype, opcdefault, opckeytype)
VALUES (
(SELECT oid FROM pg_am WHERE amname = 'gist'),
'gist__intbig_ops',
(SELECT oid FROM pg_namespace WHERE nspname = 'pg_catalog'),
1, -- UID of superuser is hardwired to 1 as of PG 7.3
(SELECT oid FROM pg_type WHERE typname = '_int4'),
false,
0);
-- get the comparators for _intments and store them in a tmp table
SELECT o.oid AS opoid, o.oprname
INTO TEMP TABLE _int_ops_tmp
FROM pg_operator o, pg_type t, pg_type tq
WHERE o.oprleft = t.oid and ( o.oprright = t.oid or o.oprright=tq.oid )
and t.typname = '_int4'
and tq.typname='query_int';
-- make sure we have the right operators
-- SELECT * from _int_ops_tmp;
-- using the tmp table, generate the amop entries
-- note: these operators are all lossy
-- _int_overlap
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 3, true, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and c.oprname = '&&';
-- _int_contains
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 7, true, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and c.oprname = '@';
-- _int_contained
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 8, true, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and c.oprname = '~';
--boolean search
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 20, true, c.opoid
FROM pg_opclass opcl, _int_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and c.oprname = '@@';
DROP TABLE _int_ops_tmp;
-- add the entries to amproc for the support methods
-- note the amprocnum numbers associated with each are specific!
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 1, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_consistent';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 2, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_union';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 3, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_compress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 4, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_decompress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 5, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_penalty';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 6, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_picksplit';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 7, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist__intbig_ops'
and proname = 'g_intbig_same';
END TRANSACTION;