openstreetmap-website/db/functions/functions.sql
Matt Amos ced8ac86ab Remove need for shared library PostgreSQL functions
This repo contains code for three functions to be loaded into PostgreSQL as a shared library:

1. `maptile_for_point`, which is used only by the `/changes` API call. This API call is little-used and IMHO should be deprecated and removed. However, even now it's hardly on the hot path for most development activities.
2. `tile_for_point`, which is used only in migrations. At this point, it seems unlikely that anyone will be doing a migration on existing data which would call this function (most developers will be running migrations on an empty database, to set it up).
3. `xid_to_int4`, which is only used for replication using Osmosis and isn't used in the Rails code at all. Hopefully this will be replaced Real Soon Now, but until then it's a quite advanced feature that most developers won't need.

Therefore, this patch proposes to replace the above three shared library functions with SQL implementations of the first two. These are _much_ slower - by a factor of about 30x, however this makes no difference when they're run on a completely empty database. In return, we're able to drop a dependency on the PostgreSQL server development package, and clean a few lines out of the installation instructions.

It's still possible to make and install the shared library functions, and I've included instructions about how to do that - although it shouldn't be necessary for the vast majority of `openstreetmap-website` developers.
2019-10-04 13:25:00 +01:00

70 lines
2.8 KiB
PL/PgSQL

--------------------------------------------------------------------------------
-- SQL versions of the C database functions.
--
-- Pure pl/pgsql versions are *slower* than the C versions, and not recommended
-- for production use. However, they are significantly easier to install, and
-- require fewer dependencies.
--------------------------------------------------------------------------------
-- tile_for_point function returns a Morton-encoded integer representing a z16
-- tile which contains the given (scaled_lon, scaled_lat) coordinate. Note that
-- these are passed into the function as (lat, lon) and should be scaled by
-- 10^7.
--
-- The Morton encoding packs two dimensions down to one with fairly good
-- spatial locality, and can be used to index points without the need for a
-- proper 2D index.
CREATE OR REPLACE FUNCTION tile_for_point(scaled_lat int4, scaled_lon int4)
RETURNS int8
AS $$
DECLARE
x int8; -- quantized x from lon,
y int8; -- quantized y from lat,
BEGIN
x := round(((scaled_lon / 10000000.0) + 180.0) * 65535.0 / 360.0);
y := round(((scaled_lat / 10000000.0) + 90.0) * 65535.0 / 180.0);
-- these bit-masks are special numbers used in the bit interleaving algorithm.
-- see https://graphics.stanford.edu/~seander/bithacks.html#InterleaveBMN
-- for the original algorithm and more details.
x := (x | (x << 8)) & 16711935; -- 0x00FF00FF
x := (x | (x << 4)) & 252645135; -- 0x0F0F0F0F
x := (x | (x << 2)) & 858993459; -- 0x33333333
x := (x | (x << 1)) & 1431655765; -- 0x55555555
y := (y | (y << 8)) & 16711935; -- 0x00FF00FF
y := (y | (y << 4)) & 252645135; -- 0x0F0F0F0F
y := (y | (y << 2)) & 858993459; -- 0x33333333
y := (y | (y << 1)) & 1431655765; -- 0x55555555
RETURN (x << 1) | y;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- maptile_for_point returns an integer representing the tile at the given zoom
-- which contains the point (scaled_lon, scaled_lat). Note that the arguments
-- are in the order (lat, lon), and should be scaled by 10^7.
--
-- The maptile_for_point function is used only for grouping the results of the
-- (deprecated?) /changes API call. Please don't use it for anything else, as
-- it might go away in the future.
CREATE OR REPLACE FUNCTION maptile_for_point(scaled_lat int8, scaled_lon int8, zoom int4)
RETURNS int4
AS $$
DECLARE
lat CONSTANT DOUBLE PRECISION := scaled_lat / 10000000.0;
lon CONSTANT DOUBLE PRECISION := scaled_lon / 10000000.0;
zscale CONSTANT DOUBLE PRECISION := 2.0 ^ zoom;
pi CONSTANT DOUBLE PRECISION := 3.141592653589793;
r_per_d CONSTANT DOUBLE PRECISION := pi / 180.0;
x int4;
y int4;
BEGIN
-- straight port of the C code. see db/functions/maptile.c
x := floor((lon + 180.0) * zscale / 360.0);
y := floor((1.0 - ln(tan(lat * r_per_d) + 1.0 / cos(lat * r_per_d)) / pi) * zscale / 2.0);
RETURN (x << zoom) | y;
END;
$$ LANGUAGE plpgsql IMMUTABLE;