1 --------------------------------------------------------------------------------
2 -- SQL versions of the C database functions.
4 -- Pure pl/pgsql versions are *slower* than the C versions, and not recommended
5 -- for production use. However, they are significantly easier to install, and
6 -- require fewer dependencies.
7 --------------------------------------------------------------------------------
9 -- tile_for_point function returns a Morton-encoded integer representing a z16
10 -- tile which contains the given (scaled_lon, scaled_lat) coordinate. Note that
11 -- these are passed into the function as (lat, lon) and should be scaled by
14 -- The Morton encoding packs two dimensions down to one with fairly good
15 -- spatial locality, and can be used to index points without the need for a
17 CREATE OR REPLACE FUNCTION tile_for_point(scaled_lat int4, scaled_lon int4)
21 x int8; -- quantized x from lon,
22 y int8; -- quantized y from lat,
24 x := round(((scaled_lon / 10000000.0) + 180.0) * 65535.0 / 360.0);
25 y := round(((scaled_lat / 10000000.0) + 90.0) * 65535.0 / 180.0);
27 -- these bit-masks are special numbers used in the bit interleaving algorithm.
28 -- see https://graphics.stanford.edu/~seander/bithacks.html#InterleaveBMN
29 -- for the original algorithm and more details.
30 x := (x | (x << 8)) & 16711935; -- 0x00FF00FF
31 x := (x | (x << 4)) & 252645135; -- 0x0F0F0F0F
32 x := (x | (x << 2)) & 858993459; -- 0x33333333
33 x := (x | (x << 1)) & 1431655765; -- 0x55555555
35 y := (y | (y << 8)) & 16711935; -- 0x00FF00FF
36 y := (y | (y << 4)) & 252645135; -- 0x0F0F0F0F
37 y := (y | (y << 2)) & 858993459; -- 0x33333333
38 y := (y | (y << 1)) & 1431655765; -- 0x55555555
42 $$ LANGUAGE plpgsql IMMUTABLE;
45 -- xid_to_int4 converts a PostgreSQL transaction ID (xid) to a 32-bit integer
46 -- which can then be used to efficiently find rows which have changed between
47 -- two given transactions. This is currently used by Osmosis to extract a
48 -- stream of edits for "diff replication" **HOWEVER** this is a pain point, as
49 -- (ab)using the xid in this way is _not_ supported or recommended by Postgres
50 -- devs. It is preventing us upgrading to PostgreSQL version 10+, and will
51 -- hopefully be replaced Real Soon Now.
53 -- From the Osmosis distribution by Brett Henderson:
54 -- https://github.com/openstreetmap/osmosis/blob/master/package/script/contrib/apidb_0.6_osmosis_xid_indexing.sql
55 CREATE OR REPLACE FUNCTION xid_to_int4(t xid)
65 IF tl >= 2147483648 THEN
66 tl := tl - 4294967296;
73 $$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;