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.
This commit is contained in:
parent
1d7e4a4c46
commit
ced8ac86ab
4 changed files with 137 additions and 29 deletions
|
@ -19,11 +19,7 @@ before_script:
|
|||
- sed -e "/idle_in_transaction_session_timeout/d" -e 's/ IMMUTABLE / /' -e "s/AS '.*libpgosm.*',/AS 'libpgosm',/" -e "/^--/d" db/structure.sql > db/structure.expected
|
||||
- psql -U postgres -c "CREATE DATABASE openstreetmap"
|
||||
- psql -U postgres -c "CREATE EXTENSION btree_gist" openstreetmap
|
||||
- make -C db/functions libpgosm.so
|
||||
- ln db/functions/libpgosm.so /tmp
|
||||
- psql -U postgres -c "CREATE FUNCTION maptile_for_point(int8, int8, int4) RETURNS int4 AS '/tmp/libpgosm', 'maptile_for_point' LANGUAGE C STRICT" openstreetmap
|
||||
- psql -U postgres -c "CREATE FUNCTION tile_for_point(int4, int4) RETURNS int8 AS '/tmp/libpgosm', 'tile_for_point' LANGUAGE C STRICT" openstreetmap
|
||||
- psql -U postgres -c "CREATE FUNCTION xid_to_int4(xid) RETURNS int4 AS '/tmp/libpgosm', 'xid_to_int4' LANGUAGE C STRICT" openstreetmap
|
||||
- psql -U postgres -f db/functions/functions.sql openstreetmap
|
||||
- cp config/travis.database.yml config/database.yml
|
||||
- cp config/example.storage.yml config/storage.yml
|
||||
- touch config/settings.local.yml
|
||||
|
|
61
INSTALL.md
61
INSTALL.md
|
@ -31,8 +31,8 @@ sudo apt-get update
|
|||
sudo apt-get install ruby2.5 libruby2.5 ruby2.5-dev bundler \
|
||||
libmagickwand-dev libxml2-dev libxslt1-dev nodejs \
|
||||
apache2 apache2-dev build-essential git-core phantomjs \
|
||||
postgresql postgresql-contrib libpq-dev postgresql-server-dev-all \
|
||||
libsasl2-dev imagemagick libffi-dev libgd-dev libarchive-dev libbz2-dev
|
||||
postgresql postgresql-contrib libpq-dev libsasl2-dev \
|
||||
imagemagick libffi-dev libgd-dev libarchive-dev libbz2-dev
|
||||
sudo gem2.5 install bundler
|
||||
```
|
||||
|
||||
|
@ -46,7 +46,7 @@ For Fedora, you can install the minimum requirements with:
|
|||
sudo dnf install ruby ruby-devel rubygem-rdoc rubygem-bundler rubygems \
|
||||
libxml2-devel js \
|
||||
gcc gcc-c++ git \
|
||||
postgresql postgresql-server postgresql-contrib postgresql-devel \
|
||||
postgresql postgresql-server postgresql-contrib \
|
||||
perl-podlators ImageMagick libffi-devel gd-devel libarchive-devel \
|
||||
bzip2-devel nodejs-yarn
|
||||
```
|
||||
|
@ -174,20 +174,12 @@ psql -d openstreetmap -c "CREATE EXTENSION btree_gist"
|
|||
|
||||
### PostgreSQL Functions
|
||||
|
||||
We need to install special functions into the PostgreSQL databases, and these are provided by a library that needs compiling first.
|
||||
There are special database functions required by a (little-used) API call, the migrations and diff replication. The former two are provided as *either* pure SQL functions or a compiled shared library. It is recommended that you start with the pure SQL versions, as described below, and only install the compiled shared library if you are running a production server making a lot of `/changes` API calls or need the diff replication functionality.
|
||||
|
||||
If you aren't sure which you need, install the SQL version below.
|
||||
|
||||
```
|
||||
cd db/functions
|
||||
make libpgosm.so
|
||||
cd ../..
|
||||
```
|
||||
|
||||
Then we create the functions within each database. We're using `pwd` to substitute in the current working directory, since PostgreSQL needs the full path.
|
||||
|
||||
```
|
||||
psql -d openstreetmap -c "CREATE FUNCTION maptile_for_point(int8, int8, int4) RETURNS int4 AS '`pwd`/db/functions/libpgosm', 'maptile_for_point' LANGUAGE C STRICT"
|
||||
psql -d openstreetmap -c "CREATE FUNCTION tile_for_point(int4, int4) RETURNS int8 AS '`pwd`/db/functions/libpgosm', 'tile_for_point' LANGUAGE C STRICT"
|
||||
psql -d openstreetmap -c "CREATE FUNCTION xid_to_int4(xid) RETURNS int4 AS '`pwd`/db/functions/libpgosm', 'xid_to_int4' LANGUAGE C STRICT"
|
||||
psql -d openstreetmap -f db/functions/functions.sql
|
||||
```
|
||||
|
||||
### Database structure
|
||||
|
@ -225,3 +217,42 @@ Note that the OSM map tiles you see aren't created from your local database - th
|
|||
# Configuration
|
||||
|
||||
After installing this software, you may need to carry out some [configuration steps](CONFIGURE.md), depending on your tasks.
|
||||
|
||||
# Installing compiled shared library database functions
|
||||
|
||||
You probably only need to do this if you are running a large, production instance of openstreetmap-website.
|
||||
|
||||
Before installing the functions, it's necessary to install the PostgreSQL server development packages. On Ubuntu this means:
|
||||
|
||||
```
|
||||
sudo apt-get install postgresql-server-dev-all
|
||||
```
|
||||
|
||||
On Fedora:
|
||||
|
||||
```
|
||||
sudo dnf install postgresql-devel
|
||||
```
|
||||
|
||||
The library then needs compiling.
|
||||
|
||||
```
|
||||
cd db/functions
|
||||
make libpgosm.so
|
||||
cd ../..
|
||||
```
|
||||
|
||||
If you previously installed the SQL versions of these functions, we'll need to delete those before adding the new ones:
|
||||
|
||||
```
|
||||
psql -d openstreetmap -c "DROP FUNCTION IF EXISTS maptile_for_point"
|
||||
psql -d openstreetmap -c "DROP FUNCTION IF EXISTS tile_for_point"
|
||||
```
|
||||
|
||||
Then we create the functions within each database. We're using `pwd` to substitute in the current working directory, since PostgreSQL needs the full path.
|
||||
|
||||
```
|
||||
psql -d openstreetmap -c "CREATE FUNCTION maptile_for_point(int8, int8, int4) RETURNS int4 AS '`pwd`/db/functions/libpgosm', 'maptile_for_point' LANGUAGE C STRICT"
|
||||
psql -d openstreetmap -c "CREATE FUNCTION tile_for_point(int4, int4) RETURNS int8 AS '`pwd`/db/functions/libpgosm', 'tile_for_point' LANGUAGE C STRICT"
|
||||
psql -d openstreetmap -c "CREATE FUNCTION xid_to_int4(xid) RETURNS int4 AS '`pwd`/db/functions/libpgosm', 'xid_to_int4' LANGUAGE C STRICT"
|
||||
```
|
||||
|
|
70
db/functions/functions.sql
Normal file
70
db/functions/functions.sql
Normal file
|
@ -0,0 +1,70 @@
|
|||
--------------------------------------------------------------------------------
|
||||
-- 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;
|
|
@ -19,7 +19,7 @@ apt-get upgrade -y
|
|||
apt-get install -y ruby2.5 libruby2.5 ruby2.5-dev \
|
||||
libmagickwand-dev libxml2-dev libxslt1-dev nodejs \
|
||||
apache2 apache2-dev build-essential git-core phantomjs \
|
||||
postgresql postgresql-contrib libpq-dev postgresql-server-dev-all \
|
||||
postgresql postgresql-contrib libpq-dev \
|
||||
libsasl2-dev imagemagick libffi-dev libgd-dev libarchive-dev libbz2-dev
|
||||
gem2.5 install rake
|
||||
gem2.5 install --version "~> 1.16.2" bundler
|
||||
|
@ -38,18 +38,29 @@ if [ "$db_user_exists" != "1" ]; then
|
|||
sudo -u vagrant psql -c "create extension btree_gist" openstreetmap
|
||||
sudo -u vagrant psql -c "create extension btree_gist" osm_test
|
||||
fi
|
||||
# build and set up postgres extensions
|
||||
pushd db/functions
|
||||
sudo -u vagrant make
|
||||
sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION maptile_for_point(int8, int8, int4) RETURNS int4 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'maptile_for_point' LANGUAGE C STRICT"
|
||||
sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION tile_for_point(int4, int4) RETURNS int8 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'tile_for_point' LANGUAGE C STRICT"
|
||||
sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION xid_to_int4(xid) RETURNS int4 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'xid_to_int4' LANGUAGE C STRICT"
|
||||
popd
|
||||
|
||||
|
||||
# install PostgreSQL functions
|
||||
sudo -u vagrant psql -d openstreetmap -f db/functions/functions.sql
|
||||
################################################################################
|
||||
# *IF* you want a vagrant image which supports replication (or perhaps you're
|
||||
# using this script to provision some other server and want replication), then
|
||||
# uncomment the following lines (until popd) and comment out the one above
|
||||
# (functions.sql).
|
||||
################################################################################
|
||||
#pushd db/functions
|
||||
#sudo -u vagrant make
|
||||
#sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION maptile_for_point(int8, int8, int4) RETURNS int4 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'maptile_for_point' LANGUAGE C ST#RICT"
|
||||
#sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION tile_for_point(int4, int4) RETURNS int8 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'tile_for_point' LANGUAGE C STRICT"
|
||||
#sudo -u vagrant psql openstreetmap -c "CREATE OR REPLACE FUNCTION xid_to_int4(xid) RETURNS int4 AS '/srv/openstreetmap-website/db/functions/libpgosm.so', 'xid_to_int4' LANGUAGE C STRICT"
|
||||
#popd
|
||||
|
||||
|
||||
# set up sample configs
|
||||
if [ ! -f config/database.yml ]; then
|
||||
sudo -u vagrant cp config/example.database.yml config/database.yml
|
||||
fi
|
||||
touch config/settings.local.yml
|
||||
# migrate the database to the latest version
|
||||
sudo -u vagrant rake db:migrate
|
||||
sudo -u vagrant bundle exec rake db:migrate
|
||||
popd
|
||||
|
|
Loading…
Add table
Reference in a new issue