name: 'Setup Postgresql and Postgis'
+inputs:
+ postgresql-version:
+ description: 'Version of PostgreSQL to install'
+ required: true
+ postgis-version:
+ description: 'Version of Postgis to install'
+ required: true
+
runs:
using: "composite"
steps:
- - name: Install postgis
+ - name: Remove existing PostgreSQL
+ run: |
+ sudo apt-get update -qq
+ sudo apt-get purge -yq postgresql*
+ shell: bash
+
+ - name: Install PostgreSQL
run: |
- sudo apt-get update -qq
- sudo apt-get install -y -qq postgresql-13-postgis-3 postgresql-13-postgis-3-scripts postgresql-server-dev-13
+ sudo apt-get install -y -qq --no-install-suggests --no-install-recommends postgresql-client-${PGVER} postgresql-${PGVER}-postgis-${POSTGISVER} postgresql-${PGVER}-postgis-${POSTGISVER}-scripts postgresql-contrib-${PGVER} postgresql-${PGVER} postgresql-server-dev-${PGVER}
shell: bash
+ env:
+ PGVER: ${{ inputs.postgresql-version }}
+ POSTGISVER: ${{ inputs.postgis-version }}
- name: Adapt postgresql configuration
run: |
- echo 'fsync = off' | sudo tee /etc/postgresql/13/main/conf.d/local.conf
- echo 'synchronous_commit = off' | sudo tee -a /etc/postgresql/13/main/conf.d/local.conf
- echo 'full_page_writes = off' | sudo tee -a /etc/postgresql/13/main/conf.d/local.conf
- echo 'shared_buffers = 1GB' | sudo tee -a /etc/postgresql/13/main/conf.d/local.conf
+ echo 'fsync = off' | sudo tee /etc/postgresql/${PGVER}/main/conf.d/local.conf
+ echo 'synchronous_commit = off' | sudo tee -a /etc/postgresql/${PGVER}/main/conf.d/local.conf
+ echo 'full_page_writes = off' | sudo tee -a /etc/postgresql/${PGVER}/main/conf.d/local.conf
+ echo 'shared_buffers = 1GB' | sudo tee -a /etc/postgresql/${PGVER}/main/conf.d/local.conf
+ echo 'port = 5432' | sudo tee -a /etc/postgresql/${PGVER}/main/conf.d/local.conf
shell: bash
+ env:
+ PGVER: ${{ inputs.postgresql-version }}
- name: Setup database
run: |
- sudo systemctl start postgresql
+ sudo systemctl restart postgresql
sudo -u postgres createuser -S www-data
sudo -u postgres createuser -s runner
shell: bash
$$
LANGUAGE plpgsql STABLE;
+DROP TYPE IF EXISTS addressdata_place;
+CREATE TYPE addressdata_place AS (
+ place_id BIGINT,
+ country_code VARCHAR(2),
+ housenumber TEXT,
+ postcode TEXT,
+ class TEXT,
+ type TEXT,
+ name HSTORE,
+ address HSTORE,
+ centroid GEOMETRY
+);
-- Compute the list of address parts for the given place.
--
RETURNS setof addressline
AS $$
DECLARE
- place RECORD;
+ place addressdata_place;
location RECORD;
current_rank_address INTEGER;
location_isaddress BOOLEAN;
-- first query osmline (interpolation lines)
IF in_housenumber >= 0 THEN
SELECT parent_place_id as place_id, country_code,
- in_housenumber::text as housenumber, postcode,
+ in_housenumber as housenumber, postcode,
'place' as class, 'house' as type,
- null::hstore as name, null::hstore as address,
+ null as name, null as address,
ST_Centroid(linegeo) as centroid
INTO place
FROM location_property_osmline
--then query tiger data
-- %NOTIGERDATA% IF 0 THEN
IF place IS NULL AND in_housenumber >= 0 THEN
- SELECT parent_place_id as place_id, 'us'::varchar(2) as country_code,
- in_housenumber::text as housenumber, postcode,
+ SELECT parent_place_id as place_id, 'us' as country_code,
+ in_housenumber as housenumber, postcode,
'place' as class, 'house' as type,
- null::hstore as name, null::hstore as address,
+ null as name, null as address,
ST_Centroid(linegeo) as centroid
INTO place
FROM location_property_tiger
-- %NOAUXDATA% IF 0 THEN
IF place IS NULL THEN
- SELECT parent_place_id as place_id, 'us'::varchar(2) as country_code,
+ SELECT parent_place_id as place_id, 'us' as country_code,
housenumber, postcode,
'place' as class, 'house' as type,
- null::hstore as name, null::hstore as address,
+ null as name, null as address,
centroid
INTO place
FROM location_property_aux
SELECT parent_place_id as place_id, country_code,
null::text as housenumber, postcode,
'place' as class, 'postcode' as type,
- null::hstore as name, null::hstore as address,
- null::geometry as centroid
+ null as name, null as address,
+ null as centroid
INTO place
FROM location_postcode
WHERE place_id = in_place_id;
select coalesce(linked_place_id, place_id) as place_id, country_code,
housenumber, postcode,
class, type,
- null::hstore as name, address,
- null::geometry as centroid
+ null as name, address,
+ null as centroid
INTO place
FROM placex where place_id = in_place_id;
END IF;