├── .gitignore ├── INSTALL.md ├── LICENSE ├── README.md ├── camp_siterel_trigger.sql ├── doimport.sh ├── gen_indexes.sql ├── gen_poi_campsites.sql ├── gen_poi_playgrounds.sql ├── get-campsites.cgi ├── get-importdate.cgi ├── osmpoidb.lua ├── poidb-update.service ├── poidb-update.timer ├── point-poly-trigger.sql ├── post-update.sh ├── post-update.sql ├── run-osm2pgsql-replication.sh ├── sitemap-index.cgi ├── sitemaps.cgi ├── update-poi-campsites-from-siterel.sql └── update-poi-campsites-with-bugs.sql /.gitignore: -------------------------------------------------------------------------------- 1 | *.pbf 2 | country_osm_grid.sql 3 | flatnode* 4 | -------------------------------------------------------------------------------- /INSTALL.md: -------------------------------------------------------------------------------- 1 | # How to setup POI database 2 | 3 | **Development Platform is Debian 12, PostgreSQL 15, PostGIS 3.3, OSM2PGSQL 2.0.0** 4 | 5 | Older Versions of OSM2PGSQL will no longer work. 6 | 7 | * Install requiered Software Packages 8 | ``` 9 | apt install aria2 curl sudo 10 | apt install -t bookworm-backports osm2pgsql 11 | ``` 12 | 13 | * Create a user for replication 14 | ``` 15 | adduser --system --group osm 16 | ``` 17 | 18 | * Create database with postgis enabled 19 | ``` 20 | sudo -u postgres createuser osm 21 | sudo -u postgres createdb -O osm poi 22 | sudo -u postgres psql -c 'CREATE EXTENSION postgis;' poi 23 | 24 | ``` 25 | 26 | * Prepare data directory 27 | ``` 28 | export OSM2BASE=/opt/osm2pgsql 29 | mkdir -p ${OSM2BASE}/data 30 | chown -r osm:osm ${OSM2BASE} 31 | `` 32 | 33 | * Download Planetfile and countr_osm_grid.sql into data directory 34 | ``` 35 | cd ${OSM2BASE}/data 36 | aria2c https://planet.openstreetmap.org/pbf/planet-latest.osm.pbf.torrent 37 | curl -s https://nominatim.org/data/country_grid.sql.gz -A OpenCampingMap |gzip -d >${OSM2BASE}/data/country_osm_grid.sql 38 | ``` 39 | 40 | * Run initial database import 41 | ``` 42 | cd ${OSM2BASE} 43 | git clone https://github.com/giggls/osmpoidb 44 | sudo -u osm osmpoidb/doimport.sh ${OSM2BASE}/data/planet*.pbf ${OSM2BASE} 45 | ``` 46 | 47 | * Init replication 48 | ``` 49 | sudo -u osm osm2pgsql-replication init -d poi --server https://planet.openstreetmap.org/replication/minute 50 | 51 | ``` 52 | 53 | * Enable update service 54 | If you did not change OSM2BASE to something else than /opt/osm2pgsql just 55 | do the following: 56 | 57 | ``` 58 | cp poidb-update.* /etc/systemd/system 59 | ``` 60 | Otherwise fix paths before copying. 61 | 62 | Finaly enable update timer: 63 | 64 | ``` 65 | systemctl enable poidb-update.timer 66 | systemctl start poidb-update.timer 67 | ``` 68 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | 2 | Apache License 3 | Version 2.0, January 2004 4 | http://www.apache.org/licenses/ 5 | 6 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 7 | 8 | 1. Definitions. 9 | 10 | "License" shall mean the terms and conditions for use, reproduction, 11 | and distribution as defined by Sections 1 through 9 of this document. 12 | 13 | "Licensor" shall mean the copyright owner or entity authorized by 14 | the copyright owner that is granting the License. 15 | 16 | "Legal Entity" shall mean the union of the acting entity and all 17 | other entities that control, are controlled by, or are under common 18 | control with that entity. For the purposes of this definition, 19 | "control" means (i) the power, direct or indirect, to cause the 20 | direction or management of such entity, whether by contract or 21 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 22 | outstanding shares, or (iii) beneficial ownership of such entity. 23 | 24 | "You" (or "Your") shall mean an individual or Legal Entity 25 | exercising permissions granted by this License. 26 | 27 | "Source" form shall mean the preferred form for making modifications, 28 | including but not limited to software source code, documentation 29 | source, and configuration files. 30 | 31 | "Object" form shall mean any form resulting from mechanical 32 | transformation or translation of a Source form, including but 33 | not limited to compiled object code, generated documentation, 34 | and conversions to other media types. 35 | 36 | "Work" shall mean the work of authorship, whether in Source or 37 | Object form, made available under the License, as indicated by a 38 | copyright notice that is included in or attached to the work 39 | (an example is provided in the Appendix below). 40 | 41 | "Derivative Works" shall mean any work, whether in Source or Object 42 | form, that is based on (or derived from) the Work and for which the 43 | editorial revisions, annotations, elaborations, or other modifications 44 | represent, as a whole, an original work of authorship. For the purposes 45 | of this License, Derivative Works shall not include works that remain 46 | separable from, or merely link (or bind by name) to the interfaces of, 47 | the Work and Derivative Works thereof. 48 | 49 | "Contribution" shall mean any work of authorship, including 50 | the original version of the Work and any modifications or additions 51 | to that Work or Derivative Works thereof, that is intentionally 52 | submitted to Licensor for inclusion in the Work by the copyright owner 53 | or by an individual or Legal Entity authorized to submit on behalf of 54 | the copyright owner. For the purposes of this definition, "submitted" 55 | means any form of electronic, verbal, or written communication sent 56 | to the Licensor or its representatives, including but not limited to 57 | communication on electronic mailing lists, source code control systems, 58 | and issue tracking systems that are managed by, or on behalf of, the 59 | Licensor for the purpose of discussing and improving the Work, but 60 | excluding communication that is conspicuously marked or otherwise 61 | designated in writing by the copyright owner as "Not a Contribution." 62 | 63 | "Contributor" shall mean Licensor and any individual or Legal Entity 64 | on behalf of whom a Contribution has been received by Licensor and 65 | subsequently incorporated within the Work. 66 | 67 | 2. Grant of Copyright License. Subject to the terms and conditions of 68 | this License, each Contributor hereby grants to You a perpetual, 69 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 70 | copyright license to reproduce, prepare Derivative Works of, 71 | publicly display, publicly perform, sublicense, and distribute the 72 | Work and such Derivative Works in Source or Object form. 73 | 74 | 3. Grant of Patent License. Subject to the terms and conditions of 75 | this License, each Contributor hereby grants to You a perpetual, 76 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 77 | (except as stated in this section) patent license to make, have made, 78 | use, offer to sell, sell, import, and otherwise transfer the Work, 79 | where such license applies only to those patent claims licensable 80 | by such Contributor that are necessarily infringed by their 81 | Contribution(s) alone or by combination of their Contribution(s) 82 | with the Work to which such Contribution(s) was submitted. If You 83 | institute patent litigation against any entity (including a 84 | cross-claim or counterclaim in a lawsuit) alleging that the Work 85 | or a Contribution incorporated within the Work constitutes direct 86 | or contributory patent infringement, then any patent licenses 87 | granted to You under this License for that Work shall terminate 88 | as of the date such litigation is filed. 89 | 90 | 4. Redistribution. You may reproduce and distribute copies of the 91 | Work or Derivative Works thereof in any medium, with or without 92 | modifications, and in Source or Object form, provided that You 93 | meet the following conditions: 94 | 95 | (a) You must give any other recipients of the Work or 96 | Derivative Works a copy of this License; and 97 | 98 | (b) You must cause any modified files to carry prominent notices 99 | stating that You changed the files; and 100 | 101 | (c) You must retain, in the Source form of any Derivative Works 102 | that You distribute, all copyright, patent, trademark, and 103 | attribution notices from the Source form of the Work, 104 | excluding those notices that do not pertain to any part of 105 | the Derivative Works; and 106 | 107 | (d) If the Work includes a "NOTICE" text file as part of its 108 | distribution, then any Derivative Works that You distribute must 109 | include a readable copy of the attribution notices contained 110 | within such NOTICE file, excluding those notices that do not 111 | pertain to any part of the Derivative Works, in at least one 112 | of the following places: within a NOTICE text file distributed 113 | as part of the Derivative Works; within the Source form or 114 | documentation, if provided along with the Derivative Works; or, 115 | within a display generated by the Derivative Works, if and 116 | wherever such third-party notices normally appear. The contents 117 | of the NOTICE file are for informational purposes only and 118 | do not modify the License. You may add Your own attribution 119 | notices within Derivative Works that You distribute, alongside 120 | or as an addendum to the NOTICE text from the Work, provided 121 | that such additional attribution notices cannot be construed 122 | as modifying the License. 123 | 124 | You may add Your own copyright statement to Your modifications and 125 | may provide additional or different license terms and conditions 126 | for use, reproduction, or distribution of Your modifications, or 127 | for any such Derivative Works as a whole, provided Your use, 128 | reproduction, and distribution of the Work otherwise complies with 129 | the conditions stated in this License. 130 | 131 | 5. Submission of Contributions. Unless You explicitly state otherwise, 132 | any Contribution intentionally submitted for inclusion in the Work 133 | by You to the Licensor shall be under the terms and conditions of 134 | this License, without any additional terms or conditions. 135 | Notwithstanding the above, nothing herein shall supersede or modify 136 | the terms of any separate license agreement you may have executed 137 | with Licensor regarding such Contributions. 138 | 139 | 6. Trademarks. This License does not grant permission to use the trade 140 | names, trademarks, service marks, or product names of the Licensor, 141 | except as required for reasonable and customary use in describing the 142 | origin of the Work and reproducing the content of the NOTICE file. 143 | 144 | 7. Disclaimer of Warranty. Unless required by applicable law or 145 | agreed to in writing, Licensor provides the Work (and each 146 | Contributor provides its Contributions) on an "AS IS" BASIS, 147 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 148 | implied, including, without limitation, any warranties or conditions 149 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 150 | PARTICULAR PURPOSE. You are solely responsible for determining the 151 | appropriateness of using or redistributing the Work and assume any 152 | risks associated with Your exercise of permissions under this License. 153 | 154 | 8. Limitation of Liability. In no event and under no legal theory, 155 | whether in tort (including negligence), contract, or otherwise, 156 | unless required by applicable law (such as deliberate and grossly 157 | negligent acts) or agreed to in writing, shall any Contributor be 158 | liable to You for damages, including any direct, indirect, special, 159 | incidental, or consequential damages of any character arising as a 160 | result of this License or out of the use or inability to use the 161 | Work (including but not limited to damages for loss of goodwill, 162 | work stoppage, computer failure or malfunction, or any and all 163 | other commercial damages or losses), even if such Contributor 164 | has been advised of the possibility of such damages. 165 | 166 | 9. Accepting Warranty or Additional Liability. While redistributing 167 | the Work or Derivative Works thereof, You may choose to offer, 168 | and charge a fee for, acceptance of support, warranty, indemnity, 169 | or other liability obligations and/or rights consistent with this 170 | License. However, in accepting such obligations, You may act only 171 | on Your own behalf and on Your sole responsibility, not on behalf 172 | of any other Contributor, and only if You agree to indemnify, 173 | defend, and hold each Contributor harmless for any liability 174 | incurred by, or claims asserted against, such Contributor by reason 175 | of your accepting any such warranty or additional liability. 176 | 177 | END OF TERMS AND CONDITIONS 178 | 179 | APPENDIX: How to apply the Apache License to your work. 180 | 181 | To apply the Apache License to your work, attach the following 182 | boilerplate notice, with the fields enclosed by brackets "[]" 183 | replaced with your own identifying information. (Don't include 184 | the brackets!) The text should be enclosed in the appropriate 185 | comment syntax for the file format. We also recommend that a 186 | file or class name and description of purpose be included on the 187 | same "printed page" as the copyright notice for easier 188 | identification within third-party archives. 189 | 190 | Copyright [yyyy] [name of copyright owner] 191 | 192 | Licensed under the Apache License, Version 2.0 (the "License"); 193 | you may not use this file except in compliance with the License. 194 | You may obtain a copy of the License at 195 | 196 | http://www.apache.org/licenses/LICENSE-2.0 197 | 198 | Unless required by applicable law or agreed to in writing, software 199 | distributed under the License is distributed on an "AS IS" BASIS, 200 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 201 | See the License for the specific language governing permissions and 202 | limitations under the License. 203 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # A POI database made from Openstreetmap data 2 | 3 | This uses a setup based on [PostGIS](http://postgis.net) and [osm2pgsql](https://osm2pgsql.org). 4 | The database is updated in a 10 minute interval. 5 | 6 | Special tables based on spatial operations can be created by sql scripts which are 7 | executed right after the hourly updates. 8 | 9 | Currently a derived table containing campsites for 10 | https://opencampingmap.org and one containing 11 | playgrounds for https://babykarte.openstreetmap.de/ 12 | are updated at this place. 13 | 14 | A special feature of these tables is something I call POI in POI which makes 15 | POI of other types located inside POI-Polygons a property of the surounding 16 | object. E.g. a restaurant located inside a polygon shaped POI tagged 17 | tourism=camp_site will add a feature of type restaurant to the outer POI. 18 | 19 | Technically this is done using a PotGIS spatial join using a function called 20 | ST_Intersects. 21 | 22 | https://brewmap.openstreetmap.de is also using this database. 23 | 24 | -------------------------------------------------------------------------------- /camp_siterel_trigger.sql: -------------------------------------------------------------------------------- 1 | 2 | DROP TRIGGER IF EXISTS delete_camp_siterel_trigger ON osm_poi_camp_siterel; 3 | 4 | CREATE OR REPLACE FUNCTION del_csr_triggerfunc() 5 | RETURNS TRIGGER 6 | LANGUAGE PLPGSQL 7 | AS 8 | $$ 9 | BEGIN 10 | -- check if refered object is camp_site and add to osm_todo_cs_trigger if so 11 | INSERT INTO osm_todo_cs_trigger(osm_id,osm_type) 12 | SELECT member_id,member_type 13 | FROM osm_poi_camp_siterel_extended 14 | WHERE member_tags ->> 'tourism' IN ('camp_site', 'caravan_site') 15 | AND site_id=OLD.site_id; 16 | 17 | RETURN OLD; 18 | END; 19 | $$; 20 | 21 | CREATE TRIGGER delete_camp_siterel_trigger BEFORE DELETE ON osm_poi_camp_siterel FOR EACH ROW EXECUTE PROCEDURE del_csr_triggerfunc(); 22 | -------------------------------------------------------------------------------- /doimport.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # 3 | # Initial database import script for osmpoidb 4 | # 5 | # (c) 2022 Sven Geggus 6 | # 7 | 8 | set -e 9 | 10 | case $# in 11 | 1) 12 | basepath=/opt/osm2pgsql 13 | ;; 14 | 2) 15 | basepath=$2 16 | ;; 17 | *) 18 | echo "usage: $0 /path/to/planetfile ?basepath?">&2 19 | exit 1 20 | ;; 21 | esac 22 | 23 | DATA_DIR=${basepath}/data 24 | CODE_DIR=${basepath}/osmpoidb 25 | DBNAME='poi' 26 | 27 | cd $DATA_DIR 28 | rm -f flatnode.dat 29 | 30 | psql -f country_osm_grid.sql $DBNAME 31 | osm2pgsql -x -s -F flatnode.dat -O flex -S $CODE_DIR/osmpoidb.lua -d $DBNAME $1 32 | psql -f $CODE_DIR/gen_indexes.sql $DBNAME 33 | psql -f $CODE_DIR/gen_poi_campsites.sql $DBNAME 34 | psql -f $CODE_DIR/update-poi-campsites-from-siterel.sql $DBNAME 35 | psql -f $CODE_DIR/update-poi-campsites-with-bugs.sql $DBNAME 36 | echo "ALTER TABLE osm_todo_campsites ADD UNIQUE (osm_type,osm_id);" |psql $DBNAME 37 | psql -f $CODE_DIR/gen_poi_playgrounds.sql $DBNAME 38 | echo "ALTER TABLE osm_todo_playgrounds ADD UNIQUE (osm_type,osm_id);" |psql $DBNAME 39 | psql -f $CODE_DIR/point-poly-trigger.sql $DBNAME 40 | psql -f $CODE_DIR/camp_siterel_trigger.sql $DBNAME 41 | 42 | -------------------------------------------------------------------------------- /gen_indexes.sql: -------------------------------------------------------------------------------- 1 | -- generate indexes for imported data 2 | 3 | -- Indexes 4 jsonb 4 | 5 | CREATE INDEX osm_poi_point_tags_index ON osm_poi_point USING GIN (tags); 6 | CREATE INDEX osm_poi_poly_tags_index ON osm_poi_poly USING GIN (tags); 7 | 8 | -- Indexes 4 osm_id (this needs an upstream fix) 9 | CREATE INDEX osm_poi_point_osm_id_idx ON osm_poi_point USING btree(osm_id); 10 | CREATE INDEX osm_poi_poly_osm_id_idx ON osm_poi_poly USING btree(osm_id); 11 | CREATE INDEX osm_poi_line_osm_id_idx ON osm_poi_line USING btree(osm_id); 12 | 13 | CREATE INDEX osm_poi_camp_siterel_member_id_idx ON osm_poi_camp_siterel USING btree(member_id); 14 | 15 | -- Indexes 4 campsites 16 | CREATE INDEX osm_poi_point_campsite_index ON osm_poi_point USING GIST (geom) WHERE (tags ->> 'tourism') = 'camp_site'; 17 | CREATE INDEX osm_poi_poly_campsite_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'tourism') = 'camp_site'; 18 | 19 | CREATE INDEX osm_poi_rels_campsite_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'tourism') = 'camp_site' AND osm_type = 'R'; 20 | CREATE INDEX osm_poi_ways_campsite_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'tourism') = 'camp_site' AND osm_type = 'W'; 21 | 22 | -- Indexes 4 playgrounds 23 | CREATE INDEX osm_poi_point_playground_index ON osm_poi_point USING GIST (geom) WHERE (tags ->> 'leisure') = 'playground'; 24 | CREATE INDEX osm_poi_poly_playground_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'leisure') = 'playground'; 25 | 26 | CREATE INDEX osm_poi_rels_playground_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'leisure') = 'playground' AND osm_type = 'R'; 27 | CREATE INDEX osm_poi_ways_playground_index ON osm_poi_poly USING GIST (geom) WHERE (tags ->> 'leisure') = 'playground' AND osm_type = 'W'; 28 | 29 | 30 | -------------------------------------------------------------------------------- /gen_poi_campsites.sql: -------------------------------------------------------------------------------- 1 | -- special data types for various osm poi objects 2 | DO $$ 3 | BEGIN 4 | IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'showertype') THEN 5 | CREATE TYPE showertype AS ENUM ('hot', 'cold', 'yes', 'no', 'untagged'); 6 | END IF; 7 | END 8 | $$; 9 | 10 | -- add or unify addr:country tag 11 | -- make sure country tag is always lowercase 12 | CREATE OR REPLACE FUNCTION unify_tags (tin jsonb, geom geometry) 13 | RETURNS jsonb 14 | AS $$ 15 | DECLARE 16 | out jsonb; 17 | country text; 18 | tag text[]; 19 | BEGIN 20 | out = tin; 21 | -- add addr:country if not already available 22 | IF NOT out ? 'addr:country' THEN 23 | SELECT 24 | country_code INTO country 25 | FROM 26 | country_osm_grid 27 | WHERE 28 | st_contains (geometry, st_centroid (geom)); 29 | IF country IS NOT NULL THEN 30 | out = out || jsonb_build_object('addr:country', country); 31 | END IF; 32 | ELSE 33 | IF (LENGTH(out ->> 'addr:country') = 2) THEN 34 | out = out || jsonb_build_object('addr:country', lower(out->>'addr:country')); 35 | ELSE 36 | SELECT 37 | country_code INTO country 38 | FROM 39 | country_osm_grid 40 | WHERE 41 | st_contains (geometry, st_centroid (geom)); 42 | IF country IS NOT NULL THEN 43 | out = out || jsonb_build_object('addr:country', country); 44 | END IF; 45 | END IF; 46 | END IF; 47 | RETURN out; 48 | END 49 | $$ 50 | LANGUAGE plpgsql; 51 | 52 | -- a view to point and polygon shaped POI objects 53 | CREATE OR REPLACE VIEW osm_poi_ptpy AS 54 | SELECT * FROM osm_poi_poly 55 | UNION ALL 56 | SELECT * FROM osm_poi_point; 57 | 58 | -- a view to all POI objects regardless off their shape 59 | CREATE OR REPLACE VIEW osm_poi_all AS 60 | SELECT * FROM osm_poi_poly 61 | UNION ALL 62 | SELECT * FROM osm_poi_point 63 | UNION ALL 64 | SELECT * FROM osm_poi_line; 65 | 66 | CREATE TABLE osm_poi_campsites_new AS 67 | SELECT 68 | poly.osm_id AS osm_id, 69 | poly.geom AS geom, 70 | unify_tags (poly.tags, poly.geom) AS tags, 71 | greatest(max(pt.timestamp),poly.timestamp) as timestamp, 72 | poly.osm_type AS osm_type, 73 | CASE WHEN poly.tags ->> 'nudism' IN ('yes', 'obligatory', 'customary', 'designated') THEN 74 | 'nudist' 75 | WHEN ((poly.tags ->> 'group_only' = 'yes') 76 | OR (poly.tags ->> 'scout' = 'yes')) THEN 77 | 'group_only' 78 | WHEN poly.tags ->> 'backcountry' = 'yes' THEN 79 | 'backcountry' 80 | WHEN ((poly.tags ->> 'tents' = 'yes') 81 | AND (poly.tags ->> 'caravans' = 'no') 82 | AND (NOT (poly.tags ? 'motorhome') OR (poly.tags ->> 'motorhome' != 'yes'))) THEN 83 | 'camping' 84 | WHEN ((poly.tags ->> 'tents' = 'no') 85 | OR ((poly.tags ->> 'tourism' = 'caravan_site') 86 | AND NOT (poly.tags ? 'tents'))) THEN 87 | 'caravan' 88 | ELSE 89 | 'standard' 90 | END AS category, 91 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'telephone', FALSE)) AS telephone, 92 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'post_box', FALSE)) AS post_box, 93 | Bool_or(COALESCE(((pt.tags ->> 'amenity' = 'drinking_water') 94 | OR ((pt.tags ->> 'man_made' = 'water_tap') AND (pt.tags ->> 'drinking_water' = 'yes')) 95 | OR (pt.tags ->> 'amenity' = 'water_point')), FALSE)) AS drinking_water, 96 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'power_supply', FALSE)) AS power_supply, 97 | -- any shop likely convenience 98 | Bool_or(COALESCE(((pt.tags ? 'shop') 99 | AND pt.tags ->> 'shop' != 'laundry'), FALSE)) AS shop, 100 | Bool_or(COALESCE(((pt.tags ->> 'amenity' = 'washing_machine') 101 | OR (pt.tags ->> 'shop' = 'laundry')), FALSE)) AS laundry, 102 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'sanitary_dump_station', FALSE)) AS sanitary_dump_station, 103 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'firepit', FALSE)) AS firepit, 104 | Bool_or(COALESCE(((pt.tags ->> 'amenity' = 'bbq') 105 | OR ((pt.tags ->> 'leisure' = 'firepit') 106 | AND (pt.tags ? 'grate') 107 | AND (pt.tags ->> 'grate' = 'yes'))), FALSE)) AS bbq, 108 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'toilets', FALSE)) AS toilets, 109 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'playground', FALSE)) AS playground, 110 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'swimming_pool', FALSE)) AS swimming_pool, 111 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'golf_course', FALSE)) AS golf_course, 112 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'miniature_golf', FALSE)) AS miniature_golf, 113 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'sauna', FALSE)) AS sauna, 114 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'fast_food', FALSE)) AS fast_food, 115 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'restaurant', FALSE)) AS restaurant, 116 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'pub', FALSE)) AS pub, 117 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'bar', FALSE)) AS bar, 118 | Bool_or(COALESCE(pt.tags ->> 'building' = 'cabin', FALSE)) AS cabin, 119 | Bool_or(COALESCE(pt.tags ->> 'building' = 'static_caravan', FALSE)) AS static_caravan, 120 | Bool_or(COALESCE(pt.tags ->> 'amenity' = 'kitchen', FALSE)) AS kitchen, 121 | Bool_or(COALESCE(((pt.tags ->> 'amenity' = 'sink') 122 | OR ((pt.tags ->> 'amenity' = 'kitchen') 123 | AND (pt.tags ? 'sink') 124 | AND (pt.tags ->> 'sink' != 'no'))), FALSE)) AS sink, 125 | Bool_or(COALESCE(((pt.tags ->> 'amenity' = 'fridge') 126 | OR ((pt.tags ->> 'amenity' = 'kitchen') 127 | AND (pt.tags ? 'fridge') 128 | AND (pt.tags ->> 'fridge' != 'no'))), FALSE)) AS fridge, 129 | Bool_or(COALESCE(pt.tags ->> 'leisure' = 'picnic_table', FALSE)) AS picnic_table, 130 | MIN( 131 | CASE 132 | WHEN (pt.tags ->> 'amenity' = 'shower') AND pt.tags ->> 'hot_water' = 'yes' then 'hot'::showertype 133 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'hot' then 'hot'::showertype 134 | WHEN (pt.tags ->> 'amenity' = 'shower') AND pt.tags ->> 'hot_water' = 'no' then 'cold'::showertype 135 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'cold' then 'cold'::showertype 136 | WHEN (pt.tags ->> 'amenity' = 'shower') AND NOT ( pt.tags ? 'hot_water') then 'yes'::showertype 137 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'yes' then 'yes'::showertype 138 | WHEN (poly.tags ->> 'shower' = 'hot') then 'hot'::showertype 139 | WHEN (poly.tags ->> 'shower' = 'cold') then 'cold'::showertype 140 | WHEN (poly.tags ->> 'shower' = 'yes') then 'yes'::showertype 141 | WHEN (poly.tags ->> 'shower' = 'outdoor') then 'yes'::showertype 142 | WHEN (poly.tags ->> 'shower' = 'no') then 'no'::showertype 143 | ELSE 'untagged'::showertype END 144 | ) as shower, 145 | -- This will produce a list of available sport facilities on the premises 146 | array_remove(array_agg(DISTINCT CASE WHEN ((pt.tags ? 'sport') 147 | AND (pt.osm_id != poly.osm_id)) THEN 148 | pt.tags ->> 'sport' 149 | END), NULL) AS sport, 150 | TRUE as visible 151 | FROM 152 | osm_poi_poly AS poly 153 | LEFT JOIN osm_poi_ptpy AS pt ON st_intersects(poly.geom, pt.geom) 154 | WHERE (poly.tags ? 'tourism') 155 | AND (poly.tags ->> 'tourism' IN ('camp_site', 'caravan_site')) 156 | GROUP BY 157 | poly.osm_id, 158 | poly.osm_type, 159 | poly.geom, 160 | poly.tags, 161 | poly.timestamp 162 | UNION ALL 163 | SELECT 164 | osm_id, 165 | geom, 166 | unify_tags(tags, geom) AS tags, 167 | timestamp, 168 | osm_type, 169 | CASE WHEN tags ->> 'nudism' IN ('yes', 'obligatory', 'customary', 'designated') THEN 170 | 'nudist' 171 | WHEN ((tags ->> 'group_only' = 'yes') 172 | OR (tags ->> 'scout' = 'yes')) THEN 173 | 'group_only' 174 | WHEN tags ->> 'backcountry' = 'yes' THEN 175 | 'backcountry' 176 | WHEN ((tags ->> 'tents' = 'yes') 177 | AND (tags ->> 'caravans' = 'no') 178 | AND (NOT (tags ? 'motorhome') OR (tags ->> 'motorhome' != 'yes'))) THEN 179 | 'camping' 180 | WHEN ((tags ->> 'tents' = 'no') 181 | OR ((tags ->> 'tourism' = 'caravan_site') 182 | AND NOT (tags ? 'tents'))) THEN 183 | 'caravan' 184 | ELSE 185 | 'standard' 186 | END AS category, 187 | FALSE AS telephone, 188 | FALSE AS post_box, 189 | FALSE AS drinking_water, 190 | FALSE AS power_supply, 191 | FALSE AS shop, 192 | FALSE AS laundry, 193 | FALSE AS sanitary_dump_station, 194 | FALSE AS firepit, 195 | FALSE AS bbq, 196 | FALSE AS toilets, 197 | FALSE AS playground, 198 | FALSE AS swimming_pool, 199 | FALSE AS golf_course, 200 | FALSE AS miniature_golf, 201 | FALSE AS sauna, 202 | FALSE AS fast_food, 203 | FALSE AS restaurant, 204 | FALSE AS pub, 205 | FALSE AS bar, 206 | FALSE AS cabin, 207 | FALSE AS static_caravan, 208 | FALSE AS kitchen, 209 | FALSE AS sink, 210 | FALSE AS fridge, 211 | FALSE AS picnic_table, 212 | CASE 213 | WHEN (tags ->> 'shower' = 'hot') THEN 'hot'::showertype 214 | WHEN (tags ->> 'shower' = 'cold') THEN 'cold'::showertype 215 | WHEN (tags ->> 'shower' = 'yes') THEN 'yes'::showertype 216 | WHEN (tags ->> 'shower' = 'outdoor') THEN 'yes'::showertype 217 | WHEN (tags ->> 'shower' = 'no') THEN 'no'::showertype 218 | ELSE 'untagged'::showertype 219 | END AS shower, 220 | '{}' AS sport, 221 | TRUE 222 | FROM 223 | osm_poi_point 224 | WHERE (tags ? 'tourism') 225 | AND (tags ->> 'tourism' IN ('camp_site', 'caravan_site')); 226 | 227 | -- geometry index 228 | CREATE INDEX osm_poi_campsites_geom_new ON osm_poi_campsites_new USING GIST (geom); 229 | 230 | -- index on osm_id (UNIQUE) maybe not needed 231 | --CREATE UNIQUE INDEX osm_poi_campsites_osm_id ON osm_poi_campsites (id); 232 | 233 | -- index on osm_type 234 | CREATE INDEX osm_poi_campsites_osm_type_new ON osm_poi_campsites_new (osm_type); 235 | 236 | GRANT SELECT ON osm_poi_campsites_new TO public; 237 | 238 | DROP TABLE IF EXISTS osm_poi_campsites; 239 | ALTER TABLE osm_poi_campsites_new RENAME TO osm_poi_campsites; 240 | ALTER INDEX osm_poi_campsites_geom_new RENAME TO osm_poi_campsites_geom; 241 | ALTER INDEX osm_poi_campsites_osm_type_new RENAME TO osm_poi_campsites_osm_type; 242 | 243 | -- extend osm_poi_camp_siterel with geometry and member tags 244 | CREATE OR REPLACE VIEW osm_poi_camp_siterel_extended AS 245 | SELECT 246 | pa.geom, 247 | pa.tags AS member_tags, 248 | sr.* 249 | FROM 250 | osm_poi_camp_siterel sr 251 | JOIN osm_poi_all pa ON sr.member_type=pa.osm_type AND sr.member_id=pa.osm_id; 252 | -------------------------------------------------------------------------------- /gen_poi_playgrounds.sql: -------------------------------------------------------------------------------- 1 | -- create TABLE osm_poi_playgrounds 2 | -- with list of equipment and sport facilities 3 | -- 4 | CREATE TABLE osm_poi_playgrounds AS 5 | SELECT 6 | poly.osm_id AS osm_id, 7 | poly.osm_type AS osm_type, 8 | poly.tags AS tags, 9 | greatest(max(CASE WHEN _st_intersects(poly.geom, pt.geom) THEN pt.timestamp END),poly.timestamp) as timestamp, 10 | poly.geom AS geom, 11 | -- This will produce a list of available playground facilities on the premises 12 | array_remove(array_agg(DISTINCT CASE WHEN (_st_intersects (poly.geom, pt.geom) 13 | AND (pt.tags ? 'playground') 14 | AND (pt.osm_id != poly.osm_id)) THEN 15 | pt.tags ->> 'playground' 16 | END), NULL) AS equipment, 17 | -- This will produce a list of available sport facilities on the premises 18 | array_remove(array_agg(DISTINCT CASE WHEN (_st_intersects (poly.geom, pt.geom) 19 | AND (pt.tags ? 'sport') 20 | AND (pt.osm_id != poly.osm_id)) THEN 21 | pt.tags ->> 'sport' 22 | END), NULL) AS sport 23 | FROM 24 | osm_poi_poly AS poly 25 | LEFT JOIN osm_poi_all AS pt ON poly.geom && pt.geom 26 | WHERE (poly.tags ->> 'leisure' = 'playground') 27 | GROUP BY 28 | poly.osm_id, 29 | poly.osm_type, 30 | poly.geom, 31 | poly.tags, 32 | poly.timestamp 33 | UNION ALL 34 | SELECT 35 | osm_id, 36 | osm_type, 37 | tags, 38 | timestamp, 39 | geom, 40 | '{}', 41 | '{}' 42 | FROM 43 | osm_poi_point 44 | WHERE (tags ->> 'leisure' = 'playground'); 45 | 46 | -- geometry index 47 | CREATE INDEX osm_poi_playgrounds_geom ON osm_poi_playgrounds USING GIST (geom); 48 | 49 | -- index on osm_id (UNIQUE) maybe not needed 50 | --CREATE UNIQUE INDEX osm_poi_playgrounds_osm_id ON osm_poi_playgrounds (id); 51 | 52 | -- index on osm_type 53 | CREATE INDEX osm_poi_playgrounds_osm_type ON osm_poi_playgrounds (osm_type); 54 | 55 | GRANT SELECT ON osm_poi_playgrounds TO public; 56 | 57 | -------------------------------------------------------------------------------- /get-campsites.cgi: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | # 3 | # This works with python2.7 and python3 4 | # 5 | # Small CGI/WSGI wrapper for JSON SQL query with BBOX or site id 6 | # 7 | # (c) 2019 Sven Geggus 8 | # 9 | # 10 | # test using the following commands: 11 | # REQUEST_METHOD=GET QUERY_STRING="bbox=-1.38,44.47,-0.95,44.81" ./get-campsites.cgi |tail +5 |jq . 12 | # REQUEST_METHOD=GET QUERY_STRING="osm_id=115074273&osm_type=way" ./get-campsites.cgi |tail +5 |jq . 13 | # REQUEST_METHOD=GET QUERY_STRING="country=li" ./get-campsites.cgi |tail +5 |jq . 14 | # 15 | import wsgiref.handlers 16 | import psycopg2 17 | import json 18 | import urllib 19 | import multipart 20 | 21 | dbconnstr="dbname=poi" 22 | 23 | sql_query=""" 24 | SELECT Jsonb_build_object('type', 'FeatureCollection', 'features', 25 | coalesce(json_agg(features.feature), '[]'::json)) 26 | FROM (SELECT CASE WHEN (osm_type != 'N') 27 | THEN Json_build_object('type', 'Feature', 28 | 'id', 'https://www.openstreetmap.org/' || CASE WHEN osm_type = 'W' THEN 'way/' ELSE 'relation/' END || osm_id, 29 | 'bbox', array[round(ST_XMin(geom)::numeric,7),round(ST_YMin(geom)::numeric,7), 30 | round(ST_XMax(geom)::numeric,7),round(ST_YMax(geom)::numeric,7)], 31 | 'geometry',St_asgeojson(ST_PointOnSurface(geom)) :: json, 'properties', 32 | CASE WHEN tags ? 'sport' THEN tags - 'sport' || Json_build_object('sport',array_to_json(string_to_array(tags ->> 'sport',';')))::jsonb ELSE tags::jsonb END 33 | || Json_build_object('category', category) ::jsonb 34 | || CASE when telephone = True THEN Json_build_object('telephone','yes') ELSE '{}' END ::jsonb 35 | || CASE when post_box = True THEN Json_build_object('post_box','yes') ELSE '{}' END ::jsonb 36 | || CASE when drinking_water = True THEN Json_build_object('drinking_water','yes') ELSE '{}' END ::jsonb 37 | || CASE when power_supply = True THEN Json_build_object('power_supply','yes') ELSE '{}' END ::jsonb 38 | || CASE when shop = True THEN Json_build_object('shop','yes') ELSE '{}' END ::jsonb 39 | || CASE when laundry = True THEN Json_build_object('laundry','yes') ELSE '{}' END ::jsonb 40 | || CASE when playground = True THEN Json_build_object('playground','yes') ELSE '{}' END ::jsonb 41 | || CASE when sanitary_dump_station = True THEN Json_build_object('sanitary_dump_station','yes') ELSE '{}' END ::jsonb 42 | || CASE when firepit = True THEN Json_build_object('openfire','yes') ELSE '{}' END ::jsonb 43 | || CASE when bbq = True THEN Json_build_object('bbq','yes') ELSE '{}' END ::jsonb 44 | || CASE when toilets = True THEN Json_build_object('toilets','yes') ELSE '{}' END ::jsonb 45 | || CASE when swimming_pool = True THEN Json_build_object('swimming_pool','yes') ELSE '{}' END ::jsonb 46 | || CASE when miniature_golf = True THEN Json_build_object('miniature_golf','yes') ELSE '{}' END ::jsonb 47 | || CASE when golf_course = True THEN Json_build_object('golf_course','yes') ELSE '{}' END ::jsonb 48 | || CASE when sauna = True THEN Json_build_object('sauna','yes') ELSE '{}' END ::jsonb 49 | || CASE when fast_food = True THEN Json_build_object('fast_food','yes') ELSE '{}' END ::jsonb 50 | || CASE when restaurant = True THEN Json_build_object('restaurant','yes') ELSE '{}' END ::jsonb 51 | || CASE when pub = True THEN Json_build_object('pub','yes') ELSE '{}' END ::jsonb 52 | || CASE when bar = True THEN Json_build_object('bar','yes') ELSE '{}' END ::jsonb 53 | || CASE when static_caravan = True THEN Json_build_object('static_caravans','yes') ELSE '{}' END ::jsonb 54 | || CASE when cabin = True THEN Json_build_object('cabins','yes') ELSE '{}' END ::jsonb 55 | || CASE when kitchen = True THEN Json_build_object('kitchen','yes') ELSE '{}' END ::jsonb 56 | || CASE when sink = True THEN Json_build_object('sink','yes') ELSE '{}' END ::jsonb 57 | || CASE when fridge = True THEN Json_build_object('fridge','yes') ELSE '{}' END ::jsonb 58 | || CASE when picnic_table = True THEN Json_build_object('picnic_table','yes') ELSE '{}' END ::jsonb 59 | || CASE when shower != 'untagged' THEN Json_build_object('shower',shower) ELSE '{}' END ::jsonb 60 | || CASE when sport != '{}' THEN Json_build_object('sport',sport) ELSE '{}' END ::jsonb 61 | ) 62 | ELSE Json_build_object('type', 'Feature', 63 | 'id', 'https://www.openstreetmap.org/node/' || osm_id, 64 | 'geometry',St_asgeojson(ST_PointOnSurface(geom)) :: json, 'properties', 65 | CASE WHEN tags ? 'sport' THEN tags - 'sport' || Json_build_object('sport',array_to_json(string_to_array(tags ->> 'sport',';')))::jsonb ELSE tags::jsonb END 66 | || Json_build_object('category', category) ::jsonb 67 | || CASE when telephone = True THEN Json_build_object('telephone','yes') ELSE '{}' END ::jsonb 68 | || CASE when post_box = True THEN Json_build_object('post_box','yes') ELSE '{}' END ::jsonb 69 | || CASE when drinking_water = True THEN Json_build_object('drinking_water','yes') ELSE '{}' END ::jsonb 70 | || CASE when power_supply = True THEN Json_build_object('power_supply','yes') ELSE '{}' END ::jsonb 71 | || CASE when shop = True THEN Json_build_object('shop','yes') ELSE '{}' END ::jsonb 72 | || CASE when laundry = True THEN Json_build_object('laundry','yes') ELSE '{}' END ::jsonb 73 | || CASE when playground = True THEN Json_build_object('playground','yes') ELSE '{}' END ::jsonb 74 | || CASE when sanitary_dump_station = True THEN Json_build_object('sanitary_dump_station','yes') ELSE '{}' END ::jsonb 75 | || CASE when firepit = True THEN Json_build_object('openfire','yes') ELSE '{}' END ::jsonb 76 | || CASE when bbq = True THEN Json_build_object('bbq','yes') ELSE '{}' END ::jsonb 77 | || CASE when toilets = True THEN Json_build_object('toilets','yes') ELSE '{}' END ::jsonb 78 | || CASE when swimming_pool = True THEN Json_build_object('swimming_pool','yes') ELSE '{}' END ::jsonb 79 | || CASE when miniature_golf = True THEN Json_build_object('miniature_golf','yes') ELSE '{}' END ::jsonb 80 | || CASE when golf_course = True THEN Json_build_object('golf_course','yes') ELSE '{}' END ::jsonb 81 | || CASE when sauna = True THEN Json_build_object('sauna','yes') ELSE '{}' END ::jsonb 82 | || CASE when fast_food = True THEN Json_build_object('fast_food','yes') ELSE '{}' END ::jsonb 83 | || CASE when restaurant = True THEN Json_build_object('restaurant','yes') ELSE '{}' END ::jsonb 84 | || CASE when pub = True THEN Json_build_object('pub','yes') ELSE '{}' END ::jsonb 85 | || CASE when bar = True THEN Json_build_object('bar','yes') ELSE '{}' END ::jsonb 86 | || CASE when static_caravan = True THEN Json_build_object('static_caravans','yes') ELSE '{}' END ::jsonb 87 | || CASE when cabin = True THEN Json_build_object('cabins','yes') ELSE '{}' END ::jsonb 88 | || CASE when kitchen = True THEN Json_build_object('kitchen','yes') ELSE '{}' END ::jsonb 89 | || CASE when sink = True THEN Json_build_object('sink','yes') ELSE '{}' END ::jsonb 90 | || CASE when fridge = True THEN Json_build_object('fridge','yes') ELSE '{}' END ::jsonb 91 | || CASE when picnic_table = True THEN Json_build_object('picnic_table','yes') ELSE '{}' END ::jsonb 92 | || CASE when shower != 'untagged' THEN Json_build_object('shower',shower) ELSE '{}' END ::jsonb 93 | || CASE when sport != '{}' THEN Json_build_object('sport',sport) ELSE '{}' END ::jsonb 94 | ) 95 | END 96 | AS feature 97 | FROM osm_poi_campsites 98 | WHERE %s 99 | ) features; 100 | """ 101 | 102 | sql_where_bbox="geom && St_setsrid('BOX3D(%f %f, %f %f)' ::box3d, 4326)" 103 | 104 | sql_where_id="osm_id = %s AND osm_type = '%s'" 105 | 106 | sql_where_country="tags ->> 'addr:country'='%s'" 107 | 108 | empty_geojson = b'{"type": "FeatureCollection", "features": []}\n' 109 | 110 | # check if bbox contains valid geographical coordinates 111 | def validate_bbox(bbox): 112 | if (bbox[0] > bbox[2]): 113 | return(False) 114 | if (bbox[1] > bbox[3]): 115 | return(False) 116 | if (bbox[0] < -180): 117 | return(False) 118 | if (bbox[1] < -90): 119 | return(False) 120 | if (bbox[2] > 180): 121 | return(False) 122 | if (bbox[3] > 90): 123 | return(False) 124 | return(True) 125 | 126 | # check if bbox contains exactly four floating point numbers 127 | def bbox2flist(bbox): 128 | coords=[] 129 | cl=bbox.split(',') 130 | if len(cl) != 4: 131 | return(coords) 132 | # validate floating point values 133 | try: 134 | for c in cl: 135 | coords.append(float(c)) 136 | except: 137 | return([]) 138 | return(coords) 139 | 140 | def application(environ, start_response): 141 | 142 | bbox = [] 143 | osm_id = [] 144 | osm_type = [] 145 | country = [] 146 | 147 | # callbacks sets required variables 148 | # for POST request + multipart module 149 | def on_field(field): 150 | if (field.field_name == b'bbox'): 151 | bbox.append(field.value.decode()) 152 | if (field.field_name == b'osm_id'): 153 | osm_id.append(field.value.decode()) 154 | if (field.field_name == b'osm_type'): 155 | osm_type.append(field.value.decode()) 156 | if (field.field_name == b'country'): 157 | country.append(field.value.decode()) 158 | 159 | def on_file(file): 160 | pass 161 | 162 | start_response('200 OK', [('Content-Type', 'application/json')]) 163 | if not 'REQUEST_METHOD' in environ: 164 | return([empty_geojson]) 165 | if environ['REQUEST_METHOD'] not in ['GET', 'POST']: 166 | return([b'{}\n']) 167 | if environ['REQUEST_METHOD'] == 'GET': 168 | if not 'QUERY_STRING' in environ: 169 | return([empty_geojson]) 170 | parms = urllib.parse.parse_qs(environ.get('QUERY_STRING', '')) 171 | bbox = parms.get('bbox') 172 | osm_id = parms.get('osm_id') 173 | osm_type = parms.get('osm_type') 174 | country = parms.get('country') 175 | else: 176 | environ['QUERY_STRING'] = '' 177 | multipart.parse_form({'Content-Type': environ['CONTENT_TYPE']}, environ['wsgi.input'], on_field, on_file) 178 | 179 | if ((bbox is not None) and (bbox != [])): 180 | # validate floating point values in bbox 181 | coords=bbox2flist(bbox[0]) 182 | if coords == []: 183 | return([empty_geojson]) 184 | # bbox sanity check 185 | if (validate_bbox(coords) == False): 186 | return([empty_geojson]) 187 | else: 188 | # country query 189 | if ((country is not None) and (country != [])): 190 | if (len(country[0]) > 3) or (len(country[0]) < 2) or (not country[0].isalpha()): 191 | return([empty_geojson]) 192 | country[0] = country[0].lower() 193 | else: 194 | # osm_id query 195 | if ((osm_id is not None) and (osm_id != []) 196 | and (osm_type is not None) and (osm_type != [])): 197 | # validate osm_id (must be numeric) 198 | if not osm_id[0].isdigit(): 199 | return([empty_geojson]) 200 | if not osm_type[0] in ["node","way","relation"]: 201 | return([empty_geojson]) 202 | else: 203 | return([empty_geojson]) 204 | 205 | try: 206 | conn = psycopg2.connect(dbconnstr) 207 | except: 208 | return([empty_geojson]) 209 | 210 | # if bbox is given country is ignored 211 | if ((bbox is not None) and (bbox != [])): 212 | q = sql_where_bbox % (coords[0],coords[1],coords[2],coords[3]) 213 | else: 214 | if ((country is not None) and (country != [])): 215 | q = sql_where_country % country[0] 216 | else: 217 | q = sql_where_id % (osm_id[0],osm_type[0][0].upper()) 218 | 219 | q = sql_query % q 220 | cur = conn.cursor() 221 | cur.execute(q) 222 | res = cur.fetchall() 223 | json_str = json.dumps(res[0][0]) 224 | conn.close() 225 | 226 | return([json_str.encode()]) 227 | 228 | 229 | if __name__ == '__main__': 230 | wsgiref.handlers.CGIHandler().run(application) 231 | -------------------------------------------------------------------------------- /get-importdate.cgi: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python3 2 | # 3 | # Query import date from osm2pgsql replicate table 4 | # 5 | # (c) 2023 Sven Geggus 6 | # 7 | import wsgiref.handlers 8 | import psycopg2 9 | from datetime import timezone 10 | from dateutil import parser 11 | 12 | dbconnstr="dbname=poi" 13 | 14 | sql_query="select value from osm2pgsql_properties where property = 'replication_timestamp';" 15 | 16 | def application(environ, start_response): 17 | start_response('200 OK', [('Content-Type', 'application/json')]) 18 | 19 | try: 20 | conn = psycopg2.connect(dbconnstr) 21 | except: 22 | return([b'{}\n']) 23 | 24 | cur = conn.cursor() 25 | cur.execute(sql_query) 26 | res = cur.fetchall() 27 | timestamp = str(parser.parse(res[0][0]).replace(tzinfo=None)).encode() 28 | conn.close() 29 | return([b'{ "importdate": "%s" }\n' % timestamp]) 30 | 31 | 32 | if __name__ == '__main__': 33 | wsgiref.handlers.CGIHandler().run(application) 34 | -------------------------------------------------------------------------------- /osmpoidb.lua: -------------------------------------------------------------------------------- 1 | -- lua script for osm2pgsql to import and update osmpoidb 2 | -- 3 | -- (c) 2022-2024 Sven Geggus 4 | 5 | -- Unify the following keys in the database 6 | local unified_keys = { 7 | booking = "reservation", 8 | phone = "contact:phone", 9 | fax = "contact:fax", 10 | website = "contact:website", 11 | email = "contact:email", 12 | mobile = "contact:mobile", 13 | url = "contact:website" 14 | }; 15 | 16 | 17 | local allowed_polygon_tags = { 18 | amenity='*', 19 | historic='*', 20 | leisure='*', 21 | shop='*', 22 | tourism='*', 23 | industrial='*', 24 | craft='*', 25 | man_made='*', 26 | healthcare='*', 27 | emergency='*', 28 | playground='*', 29 | camp_site='*', 30 | building={'cabin','static_caravan'} 31 | } 32 | 33 | local allowed_line_tags = { 34 | playground='*', 35 | amenity='*' 36 | } 37 | 38 | local allowed_point_tags = { 39 | amenity='*', 40 | historic='*', 41 | leisure='*', 42 | shop='*', 43 | tourism='*', 44 | industrial='*', 45 | craft='*', 46 | man_made='*', 47 | healthcare='*', 48 | emergency='*', 49 | highway='*', 50 | -- It is IMO a bad tagging decision that we need those here :( 51 | playground='*', 52 | camp_site='*', 53 | building={'cabin','static_caravan'} 54 | } 55 | 56 | function contains(list, x) 57 | for _, v in pairs(list) do 58 | if v == x then return true end 59 | end 60 | return false 61 | end 62 | 63 | function has_any_of(tags, list) 64 | for k,v in pairs(tags) do 65 | if list[k] then 66 | if (list[k] == '*') then 67 | return true 68 | else 69 | if contains(list[k],v) then 70 | return true 71 | end 72 | end 73 | end 74 | end 75 | return false 76 | end 77 | 78 | -- unify_keys and 'addr:country' if set 79 | function unify_keys(tags) 80 | for k,v in pairs(unified_keys) do 81 | if (tags[k] ~= nil) then 82 | tags[unified_keys[k]]=tags[k]; 83 | tags[k]=nil; 84 | end 85 | end 86 | end 87 | 88 | -- The global variable "osm2pgsql" is used to talk to the main osm2pgsql code. 89 | -- You can, for instance, get the version of osm2pgsql: 90 | print('osm2pgsql version: ' .. osm2pgsql.version) 91 | 92 | -- A place to store the SQL tables we will define shortly. 93 | local tables = {} 94 | 95 | tables.point = osm2pgsql.define_table{ 96 | name = 'osm_poi_point', 97 | ids = { type = 'any', id_column = 'osm_id', type_column = 'osm_type' }, 98 | columns = { 99 | { column = 'id', sql_type = 'serial', create_only=true }, 100 | { column = 'timestamp', sql_type = 'timestamp' }, 101 | { column = 'tags', type = 'jsonb' }, 102 | { column = 'geom', type = 'point', projection = 'latlong' }, 103 | } 104 | } 105 | 106 | tables.line = osm2pgsql.define_table{ 107 | name = 'osm_poi_line', 108 | ids = { type = 'any', id_column = 'osm_id', type_column = 'osm_type' }, 109 | columns = { 110 | { column = 'id', sql_type = 'serial', create_only=true }, 111 | { column = 'timestamp', sql_type = 'timestamp' }, 112 | { column = 'tags', type = 'jsonb' }, 113 | { column = 'geom', type = 'linestring', projection = 'latlong' }, 114 | } 115 | } 116 | 117 | tables.polygon = osm2pgsql.define_table{ 118 | name = 'osm_poi_poly', 119 | ids = { type = 'any', id_column = 'osm_id', type_column = 'osm_type' }, 120 | columns = { 121 | { column = 'id', sql_type = 'serial', create_only=true }, 122 | { column = 'timestamp', sql_type = 'timestamp' }, 123 | { column = 'tags', type = 'jsonb' }, 124 | { column = 'geom', type = 'multipolygon', projection = 'latlong' }, 125 | } 126 | } 127 | 128 | tables.siterel = osm2pgsql.define_table{ 129 | name = 'osm_poi_camp_siterel', 130 | ids = { type = 'relation', id_column = 'site_id'}, 131 | columns = { 132 | { column = 'id', sql_type = 'serial', create_only=true }, 133 | { column = 'timestamp', sql_type = 'timestamp' }, 134 | { column = 'member_id', type = 'bigint' }, 135 | { column = 'member_type', type = 'text' }, 136 | { column = 'site_tags', type = 'jsonb' } 137 | } 138 | } 139 | 140 | tables.todocs = osm2pgsql.define_table{ 141 | name = 'osm_todo_campsites', 142 | ids = { type = 'any', id_column = 'osm_id', type_column = 'osm_type' }, 143 | columns = {{ column = 'is_cs', type = 'bool' }} 144 | } 145 | 146 | tables.todocsr = osm2pgsql.define_table{ 147 | name = 'osm_todo_camp_siterel', 148 | ids = { type = 'relation', id_column = 'osm_id'}, 149 | columns = { 150 | { column = 'id', sql_type = 'serial', create_only=true } 151 | } 152 | } 153 | 154 | tables.todopg = osm2pgsql.define_table{ 155 | name = 'osm_todo_playgrounds', 156 | ids = { type = 'any', id_column = 'osm_id', type_column = 'osm_type' }, 157 | columns = {{ column = 'is_pg', type = 'bool' }} 158 | } 159 | 160 | -- Debug output: Show definition of tables 161 | for name, table in pairs(tables) do 162 | print("\ntable '" .. name .. "':") 163 | print(" name='" .. table:name() .. "'") 164 | -- print(" columns=" .. inspect(table:columns())) 165 | end 166 | 167 | -- In append mode add new objects into to tables to be processed 168 | -- in post-update SQL script 169 | function fill_todo_tables(object) 170 | 171 | local is_cs = false; 172 | if contains({'caravan_site','camp_site'},object.tags.tourism) then 173 | is_cs = true; 174 | end 175 | tables.todocs:insert({ 176 | osm_id = object.id, 177 | osm_type = object.type, 178 | is_cs = is_cs 179 | }) 180 | 181 | local is_pg = false; 182 | if (object.tags.leisure == 'playground') then 183 | is_pg = true; 184 | end 185 | tables.todopg:insert({ 186 | osm_id = object.id, 187 | osm_type = object.type, 188 | is_pg = is_pg 189 | }) 190 | end 191 | 192 | -- Called for every node in the input. The `object` argument contains all the 193 | -- attributes of the node like `id`, `version`, etc. as well as all tags as a 194 | -- Lua table (`object.tags`). 195 | function osm2pgsql.process_node(object) 196 | 197 | if not (has_any_of(object.tags, allowed_point_tags)) then 198 | return 199 | end 200 | 201 | unify_keys(object.tags) 202 | 203 | if (osm2pgsql.mode == 'append') then 204 | fill_todo_tables(object) 205 | end 206 | 207 | tables.point:insert({ 208 | tags = object.tags, 209 | timestamp = os.date('!%Y-%m-%dT%H:%M:%SZ', object.timestamp), 210 | geom = object:as_point() 211 | }) 212 | 213 | end 214 | 215 | -- Called for every way in the input. The `object` argument contains the same 216 | -- information as with nodes and additionally a boolean `is_closed` flag and 217 | -- the list of node IDs referenced by the way (`object.nodes`). 218 | function osm2pgsql.process_way(object) 219 | 220 | if not ((has_any_of(object.tags, allowed_polygon_tags)) or has_any_of(object.tags, allowed_line_tags)) then 221 | return 222 | end 223 | 224 | unify_keys(object.tags) 225 | 226 | if (osm2pgsql.mode == 'append') then 227 | fill_todo_tables(object) 228 | end 229 | 230 | -- Very simple check to decide whether a way is a polygon or not. 231 | -- Good enough in this case as we have only a small list of allowed tags 232 | if object.is_closed then 233 | if (has_any_of(object.tags, allowed_polygon_tags)) then 234 | tables.polygon:insert({ 235 | tags = object.tags, 236 | timestamp = os.date('!%Y-%m-%dT%H:%M:%SZ', object.timestamp), 237 | geom = object:as_multipolygon() 238 | }) 239 | end 240 | else 241 | if (has_any_of(object.tags, allowed_line_tags)) then 242 | tables.line:insert({ 243 | tags = object.tags, 244 | timestamp = os.date('!%Y-%m-%dT%H:%M:%SZ', object.timestamp), 245 | geom = object:as_linestring() 246 | }) 247 | end 248 | end 249 | end 250 | 251 | -- Called for every relation in the input. The `object` argument contains the 252 | -- same information as with nodes and additionally an array of members 253 | -- (`object.members`). 254 | function osm2pgsql.process_relation(object) 255 | 256 | if not (has_any_of(object.tags, allowed_polygon_tags)) and not (object.tags.type == 'site') then 257 | return 258 | end 259 | 260 | unify_keys(object.tags) 261 | 262 | if object.tags.type == 'site' then 263 | if contains({'caravan_site','camp_site'},object.tags.tourism) or 264 | contains({'caravan_site','camp_site'},object.tags.site) then 265 | for _,member in ipairs(object.members) do 266 | tables.siterel:insert({ 267 | member_id = member.ref, 268 | member_type = string.upper(member.type), 269 | site_tags = object.tags, 270 | timestamp = os.date('!%Y-%m-%dT%H:%M:%SZ', object.timestamp) 271 | }) 272 | if (osm2pgsql.mode == 'append') then 273 | tables.todocsr:insert({osm_id = object.id}) 274 | end 275 | end 276 | end 277 | end 278 | 279 | -- OSM multipolygons 280 | if object.tags.type == 'multipolygon' then 281 | if (osm2pgsql.mode == 'append') then 282 | fill_todo_tables(object) 283 | end 284 | tables.polygon:insert({ 285 | tags = object.tags, 286 | timestamp = os.date('!%Y-%m-%dT%H:%M:%SZ', object.timestamp), 287 | geom = object:as_multipolygon() 288 | }) 289 | end 290 | end 291 | 292 | -------------------------------------------------------------------------------- /poidb-update.service: -------------------------------------------------------------------------------- 1 | [Unit] 2 | Description=Call osm2pgsql replication script 3 | 4 | [Service] 5 | Type=simple 6 | User=osm 7 | Group=osm 8 | Environment="PATH=/usr/local/bin:/usr/bin:/bin" 9 | ExecStart=/opt/osm2pgsql/osmpoidb/run-osm2pgsql-replication.sh /opt/osm2pgsql 10 | 11 | -------------------------------------------------------------------------------- /poidb-update.timer: -------------------------------------------------------------------------------- 1 | [Unit] 2 | Description=Run osm2pgsql replication every 10 minutes 3 | After=network.target postgresql.service 4 | 5 | [Timer] 6 | # Time to wait after booting before we run first time 7 | OnBootSec=5min 8 | # Time between running each consecutive time 9 | OnUnitActiveSec=10min 10 | Unit=poidb-update.service 11 | 12 | [Install] 13 | WantedBy=multi-user.target 14 | -------------------------------------------------------------------------------- /point-poly-trigger.sql: -------------------------------------------------------------------------------- 1 | 2 | -- the table we write campsite ids to which need to get refreshed 3 | CREATE TABLE IF NOT EXISTS osm_todo_cs_trigger (osm_type char(1), osm_id bigint); 4 | 5 | -- the table we write playground ids to which need to get refreshed 6 | CREATE TABLE IF NOT EXISTS osm_todo_pg_trigger (osm_type char(1), osm_id bigint); 7 | 8 | DROP TRIGGER IF EXISTS delete_point_trigger ON osm_poi_point; 9 | DROP TRIGGER IF EXISTS delete_poly_trigger ON osm_poi_poly; 10 | 11 | CREATE OR REPLACE FUNCTION delete_object() 12 | RETURNS TRIGGER 13 | LANGUAGE PLPGSQL 14 | AS 15 | $$ 16 | BEGIN 17 | -- check if object is playground and delete if so 18 | IF (OLD.tags ->> 'leisure' = 'playground') THEN 19 | DELETE FROM osm_poi_playgrounds where osm_id=OLD.osm_id AND osm_type=OLD.osm_type; 20 | ELSE 21 | -- if object intersected with a polygon shaped playground add playground object to table osm_todo_pg_trigger 22 | INSERT INTO osm_todo_pg_trigger(osm_id,osm_type) 23 | SELECT osm_id,osm_type 24 | FROM osm_poi_poly 25 | WHERE (tags ->> 'leisure' = 'playground') 26 | AND ST_Intersects((SELECT geom from osm_poi_all WHERE osm_id=OLD.osm_id AND osm_type=OLD.osm_type limit 1),geom); 27 | END IF; 28 | 29 | -- check if object is campsite and delete if so 30 | IF (OLD.tags ->> 'tourism' IN ('camp_site', 'caravan_site')) THEN 31 | DELETE FROM osm_poi_campsites where osm_id=OLD.osm_id AND osm_type=OLD.osm_type; 32 | ELSE 33 | -- if object intersected with a polygon shaped campsite add campsite object to table osm_todo_cs_trigger 34 | INSERT INTO osm_todo_cs_trigger(osm_id,osm_type) 35 | SELECT osm_id,osm_type 36 | FROM osm_poi_poly 37 | WHERE (tags ->> 'tourism' IN ('camp_site', 'caravan_site')) 38 | AND ST_Intersects((SELECT geom from osm_poi_all WHERE osm_id=OLD.osm_id AND osm_type=OLD.osm_type limit 1),geom); 39 | END IF; 40 | 41 | RETURN OLD; 42 | END; 43 | $$; 44 | 45 | CREATE TRIGGER delete_point_trigger BEFORE DELETE ON osm_poi_point FOR EACH ROW EXECUTE PROCEDURE delete_object(); 46 | CREATE TRIGGER delete_poly_trigger BEFORE DELETE ON osm_poi_poly FOR EACH ROW EXECUTE PROCEDURE delete_object(); 47 | -------------------------------------------------------------------------------- /post-update.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | DBNAME='poi' 4 | 5 | set -e 6 | 7 | echo -n "$(date +'%Y-%m-%d %H:%M:%S') calling post-update.sql..." 8 | t1=$(date +%s) 9 | psql -q -f post-update.sql $DBNAME 10 | t2=$(date +%s) 11 | echo " done in $(expr $t2 - $t1)s." 12 | 13 | echo -n "$(date +'%Y-%m-%d %H:%M:%S') calling update-poi-campsites-with-bugs.sql..." 14 | psql -q -f update-poi-campsites-with-bugs.sql $DBNAME 15 | t1=$(date +%s) 16 | echo " done in $(expr $t1 - $t2)s." 17 | 18 | 19 | -------------------------------------------------------------------------------- /post-update.sql: -------------------------------------------------------------------------------- 1 | -- Post update stuff for TABLE osm_poi_campsites 2 | 3 | -- This will insert all campsites which are affected by other POI updates 4 | -- which are located inside their site area 5 | INSERT INTO osm_todo_campsites(osm_id,osm_type,is_cs) 6 | SELECT pa.osm_id,pa.osm_type,true 7 | FROM osm_poi_all pa, 8 | ( 9 | SELECT pa.osm_type,pa.osm_id,pa.geom 10 | FROM osm_poi_all pa 11 | JOIN osm_todo_campsites tc 12 | ON tc.osm_id=pa.osm_id AND tc.osm_type=pa.osm_type 13 | WHERE tc.is_cs=false 14 | ) as tc 15 | WHERE (pa.tags ->> 'tourism' IN ('camp_site', 'caravan_site')) 16 | AND ST_Intersects(tc.geom,pa.geom) 17 | ON CONFLICT (osm_id,osm_type) DO NOTHING; 18 | 19 | -- processing of non campsite objects is done at this stage, 20 | -- thus delete them 21 | DELETE FROM osm_todo_campsites WHERE is_cs=false; 22 | 23 | -- This will add all campsites where an internal POI has been deleted 24 | -- The delete trigger function has added them to osm_todo_cs_trigger 25 | INSERT INTO osm_todo_campsites(osm_id,osm_type,is_cs) 26 | SELECT osm_id,osm_type,true 27 | FROM osm_todo_cs_trigger 28 | ON CONFLICT (osm_id,osm_type) DO NOTHING; 29 | 30 | -- This will insert all campsites which are affected by POI updates 31 | -- which are members of a NEW camp_site site-relation 32 | -- Modified camp_site site-relations have been already added via delete trigger 33 | INSERT INTO osm_todo_campsites(osm_id,osm_type,is_cs) 34 | SELECT DISTINCT csre.member_id,csre.member_type,true 35 | FROM osm_poi_camp_siterel_extended csre,osm_todo_camp_siterel tcsr 36 | WHERE csre.site_id=tcsr.osm_id 37 | AND csre.member_tags ->> 'tourism' IN ('camp_site', 'caravan_site') 38 | ON CONFLICT (osm_id,osm_type) DO NOTHING; 39 | 40 | -- Make osm_id in table osm_todo_camp_siterel UNIQUE 41 | DELETE FROM osm_todo_camp_siterel a USING osm_todo_camp_siterel b WHERE a.id < b.id AND a.osm_id = b.osm_id; 42 | 43 | BEGIN; 44 | DELETE FROM osm_poi_campsites 45 | USING osm_todo_campsites 46 | WHERE osm_poi_campsites.osm_id = osm_todo_campsites.osm_id 47 | AND osm_poi_campsites.osm_type = osm_todo_campsites.osm_type; 48 | 49 | INSERT INTO osm_poi_campsites 50 | SELECT 51 | poly.osm_id AS osm_id, 52 | poly.geom AS geom, 53 | unify_tags (poly.tags, poly.geom) AS tags, 54 | greatest(max(CASE WHEN _st_intersects(poly.geom, pt.geom) THEN pt.timestamp END),poly.timestamp) as timestamp, 55 | poly.osm_type AS osm_type, 56 | CASE WHEN poly.tags ->> 'nudism' IN ('yes', 'obligatory', 'customary', 'designated') THEN 57 | 'nudist' 58 | WHEN ((poly.tags ->> 'group_only' = 'yes') 59 | OR (poly.tags ->> 'scout' = 'yes')) THEN 60 | 'group_only' 61 | WHEN poly.tags ->> 'backcountry' = 'yes' THEN 62 | 'backcountry' 63 | WHEN ((poly.tags ->> 'tents' = 'yes') 64 | AND (poly.tags ->> 'caravans' = 'no') 65 | AND (NOT (poly.tags ? 'motorhome') OR (poly.tags ->> 'motorhome' != 'yes'))) THEN 66 | 'camping' 67 | WHEN ((poly.tags ->> 'tents' = 'no') 68 | OR ((poly.tags ->> 'tourism' = 'caravan_site') 69 | AND NOT (poly.tags ? 'tents'))) THEN 70 | 'caravan' 71 | ELSE 72 | 'standard' 73 | END AS category, 74 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 75 | AND pt.tags ->> 'amenity' = 'telephone', FALSE)) AS telephone, 76 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 77 | AND pt.tags ->> 'amenity' = 'post_box', FALSE)) AS post_box, 78 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 79 | AND ((pt.tags ->> 'amenity' = 'drinking_water') 80 | OR ((pt.tags ->> 'man_made' = 'water_tap') AND (pt.tags ->> 'drinking_water' = 'yes')) 81 | OR (pt.tags ->> 'amenity' = 'water_point')), FALSE)) AS drinking_water, 82 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 83 | AND pt.tags ->> 'amenity' = 'power_supply', FALSE)) AS power_supply, 84 | -- any shop likely convenience 85 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 86 | AND ((pt.tags ? 'shop') 87 | AND pt.tags ->> 'shop' != 'laundry'), FALSE)) AS shop, 88 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 89 | AND ((pt.tags ->> 'amenity' = 'washing_machine') 90 | OR (pt.tags ->> 'shop' = 'laundry')), FALSE)) AS laundry, 91 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 92 | AND pt.tags ->> 'amenity' = 'sanitary_dump_station', FALSE)) AS sanitary_dump_station, 93 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 94 | AND pt.tags ->> 'leisure' = 'firepit', FALSE)) AS firepit, 95 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 96 | AND ((pt.tags ->> 'amenity' = 'bbq') 97 | OR ((pt.tags ->> 'leisure' = 'firepit') 98 | AND (pt.tags ? 'grate') 99 | AND (pt.tags ->> 'grate' = 'yes'))), FALSE)) AS bbq, 100 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 101 | AND pt.tags ->> 'amenity' = 'toilets', FALSE)) AS toilets, 102 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 103 | AND pt.tags ->> 'leisure' = 'playground', FALSE)) AS playground, 104 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 105 | AND pt.tags ->> 'leisure' = 'swimming_pool', FALSE)) AS swimming_pool, 106 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 107 | AND pt.tags ->> 'leisure' = 'golf_course', FALSE)) AS golf_course, 108 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 109 | AND pt.tags ->> 'leisure' = 'miniature_golf', FALSE)) AS miniature_golf, 110 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 111 | AND pt.tags ->> 'leisure' = 'sauna', FALSE)) AS sauna, 112 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 113 | AND pt.tags ->> 'amenity' = 'fast_food', FALSE)) AS fast_food, 114 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 115 | AND pt.tags ->> 'amenity' = 'restaurant', FALSE)) AS restaurant, 116 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 117 | AND pt.tags ->> 'amenity' = 'pub', FALSE)) AS pub, 118 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 119 | AND pt.tags ->> 'amenity' = 'bar', FALSE)) AS bar, 120 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 121 | AND pt.tags ->> 'building' = 'cabin', FALSE)) AS cabin, 122 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 123 | AND pt.tags ->> 'building' = 'static_caravan', FALSE)) AS static_caravan, 124 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 125 | AND pt.tags ->> 'amenity' = 'kitchen', FALSE)) AS kitchen, 126 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 127 | AND ((pt.tags ->> 'amenity' = 'sink') 128 | OR ((pt.tags ->> 'amenity' = 'kitchen') 129 | AND (pt.tags ? 'sink') 130 | AND (pt.tags ->> 'sink' != 'no'))), FALSE)) AS sink, 131 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 132 | AND ((pt.tags ->> 'amenity' = 'fridge') 133 | OR ((pt.tags ->> 'amenity' = 'kitchen') 134 | AND (pt.tags ? 'fridge') 135 | AND (pt.tags ->> 'fridge' != 'no'))), FALSE)) AS fridge, 136 | Bool_or(COALESCE(_st_intersects (poly.geom, pt.geom) 137 | AND pt.tags ->> 'leisure' = 'picnic_table', FALSE)) AS picnic_table, 138 | MIN( 139 | CASE 140 | WHEN (pt.tags ->> 'amenity' = 'shower') AND pt.tags ->> 'hot_water' = 'yes' then 'hot'::showertype 141 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'hot' then 'hot'::showertype 142 | WHEN (pt.tags ->> 'amenity' = 'shower') AND pt.tags ->> 'hot_water' = 'no' then 'cold'::showertype 143 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'cold' then 'cold'::showertype 144 | WHEN (pt.tags ->> 'amenity' = 'shower') AND NOT ( pt.tags ? 'hot_water') then 'yes'::showertype 145 | WHEN (pt.tags ->> 'amenity' = 'toilets') AND pt.tags ->> 'shower' = 'yes' then 'yes'::showertype 146 | WHEN (poly.tags ->> 'shower' = 'hot') then 'hot'::showertype 147 | WHEN (poly.tags ->> 'shower' = 'cold') then 'cold'::showertype 148 | WHEN (poly.tags ->> 'shower' = 'yes') then 'yes'::showertype 149 | WHEN (poly.tags ->> 'shower' = 'outdoor') then 'yes'::showertype 150 | WHEN (poly.tags ->> 'shower' = 'no') then 'no'::showertype 151 | ELSE 'untagged'::showertype END 152 | ) as shower, 153 | -- This will produce a list of available sport facilities on the premises 154 | array_remove(array_agg(DISTINCT CASE WHEN (_st_intersects (poly.geom, pt.geom) 155 | AND (pt.tags ? 'sport') 156 | AND (pt.osm_id != poly.osm_id)) THEN 157 | pt.tags ->> 'sport' 158 | END), NULL) AS sport, 159 | TRUE as visible 160 | FROM 161 | osm_todo_campsites tc, 162 | osm_poi_poly AS poly 163 | LEFT JOIN osm_poi_ptpy AS pt ON poly.geom && pt.geom 164 | WHERE 165 | poly.osm_id=tc.osm_id AND poly.osm_type=tc.osm_type 166 | GROUP BY 167 | poly.osm_id, 168 | poly.osm_type, 169 | poly.geom, 170 | poly.tags, 171 | poly.timestamp 172 | UNION ALL 173 | SELECT 174 | pp.osm_id, 175 | pp.geom, 176 | unify_tags (pp.tags, pp.geom) AS tags, 177 | pp.timestamp, 178 | pp.osm_type, 179 | CASE WHEN pp.tags ->> 'nudism' IN ('yes', 'obligatory', 'customary', 'designated') THEN 180 | 'nudist' 181 | WHEN ((pp.tags ->> 'group_only' = 'yes') 182 | OR (pp.tags ->> 'scout' = 'yes')) THEN 183 | 'group_only' 184 | WHEN pp.tags ->> 'backcountry' = 'yes' THEN 185 | 'backcountry' 186 | WHEN ((pp.tags ->> 'tents' = 'yes') 187 | AND (pp.tags ->> 'caravans' = 'no') 188 | AND (NOT (pp.tags ? 'motorhome') OR (pp.tags ->> 'motorhome' != 'yes'))) THEN 189 | 'camping' 190 | WHEN ((pp.tags ->> 'tents' = 'no') 191 | OR ((pp.tags ->> 'tourism' = 'caravan_site') 192 | AND NOT (pp.tags ? 'tents'))) THEN 193 | 'caravan' 194 | ELSE 195 | 'standard' 196 | END AS category, 197 | FALSE AS telephone, 198 | FALSE AS post_box, 199 | FALSE AS drinking_water, 200 | FALSE AS power_supply, 201 | FALSE AS shop, 202 | FALSE AS laundry, 203 | FALSE AS sanitary_dump_station, 204 | FALSE AS firepit, 205 | FALSE AS bbq, 206 | FALSE AS toilets, 207 | FALSE AS playground, 208 | FALSE AS swimming_pool, 209 | FALSE AS golf_course, 210 | FALSE AS miniature_golf, 211 | FALSE AS sauna, 212 | FALSE AS fast_food, 213 | FALSE AS restaurant, 214 | FALSE AS pub, 215 | FALSE AS bar, 216 | FALSE AS cabin, 217 | FALSE AS static_caravan, 218 | FALSE AS kitchen, 219 | FALSE AS sink, 220 | FALSE AS fridge, 221 | FALSE AS picnic_table, 222 | CASE 223 | WHEN (tags ->> 'shower' = 'hot') THEN 'hot'::showertype 224 | WHEN (tags ->> 'shower' = 'cold') THEN 'cold'::showertype 225 | WHEN (tags ->> 'shower' = 'yes') THEN 'yes'::showertype 226 | WHEN (tags ->> 'shower' = 'outdoor') THEN 'yes'::showertype 227 | WHEN (tags ->> 'shower' = 'no') THEN 'no'::showertype 228 | ELSE 'untagged'::showertype 229 | END AS shower, 230 | '{}' AS sport, 231 | TRUE 232 | FROM 233 | osm_todo_campsites tc, 234 | osm_poi_point pp 235 | WHERE pp.osm_id=tc.osm_id AND pp.osm_type=tc.osm_type; 236 | 237 | -- Now we also need to update those sites which are part of a new or modified site relation 238 | UPDATE 239 | osm_poi_campsites cs 240 | SET 241 | -- ignore addr:country from site relation 242 | tags = cs.tags || (sr.site_tags - 'type'::text - 'site'::text - 'addr:country'::text) 243 | FROM ( 244 | SELECT 245 | member_id, 246 | member_type, 247 | site_tags 248 | FROM 249 | osm_poi_camp_siterel_extended csre, osm_todo_camp_siterel tdsr 250 | WHERE 251 | member_tags ->> 'tourism' = 'camp_site' AND csre.site_id=tdsr.osm_id 252 | ) sr 253 | WHERE 254 | cs.osm_id = sr.member_id 255 | AND cs.osm_type = sr.member_type; 256 | 257 | -- telephone in site relations 258 | UPDATE 259 | osm_poi_campsites cs 260 | SET 261 | telephone = TRUE 262 | FROM ( 263 | SELECT 264 | s.member_id, 265 | s.member_type 266 | FROM 267 | osm_poi_camp_siterel_extended s 268 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 269 | AND s.member_tags ->> 'tourism' = 'camp_site' 270 | AND r.member_tags ->> 'amenity' = 'telephone') sr 271 | WHERE 272 | cs.osm_id = sr.member_id 273 | AND cs.osm_type = sr.member_type; 274 | 275 | -- post_box in site relations 276 | UPDATE 277 | osm_poi_campsites cs 278 | SET 279 | post_box = TRUE 280 | FROM ( 281 | SELECT 282 | s.member_id, 283 | s.member_type 284 | FROM 285 | osm_poi_camp_siterel_extended s 286 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 287 | AND s.member_tags ->> 'tourism' = 'camp_site' 288 | AND r.member_tags ->> 'amenity' = 'post_box') sr 289 | WHERE 290 | cs.osm_id = sr.member_id 291 | AND cs.osm_type = sr.member_type; 292 | 293 | -- drinking_water in site relations 294 | UPDATE 295 | osm_poi_campsites cs 296 | SET 297 | drinking_water = TRUE 298 | FROM ( 299 | SELECT 300 | s.member_id, 301 | s.member_type 302 | FROM 303 | osm_poi_camp_siterel_extended s 304 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 305 | AND s.member_tags ->> 'tourism' = 'camp_site' 306 | AND r.member_tags ->> 'amenity' = 'drinking_water') sr 307 | WHERE 308 | cs.osm_id = sr.member_id 309 | AND cs.osm_type = sr.member_type; 310 | 311 | -- any shop (likely convenience) in site relations 312 | UPDATE 313 | osm_poi_campsites cs 314 | SET 315 | shop = TRUE 316 | FROM ( 317 | SELECT 318 | s.member_id, 319 | s.member_type 320 | FROM 321 | osm_poi_camp_siterel_extended s 322 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 323 | AND s.member_tags ->> 'tourism' = 'camp_site' 324 | AND (r.member_tags ? 'shop' 325 | AND r.member_tags ->> 'shop' != 'laundry')) sr 326 | WHERE 327 | cs.osm_id = sr.member_id 328 | AND cs.osm_type = sr.member_type; 329 | 330 | -- laundry or washing machine in site relations 331 | UPDATE 332 | osm_poi_campsites cs 333 | SET 334 | laundry = TRUE 335 | FROM ( 336 | SELECT 337 | s.member_id, 338 | s.member_type 339 | FROM 340 | osm_poi_camp_siterel_extended s 341 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 342 | AND s.member_tags ->> 'tourism' = 'camp_site' 343 | AND ((r.member_tags ->> 'amenity' = 'washing_machine') 344 | OR (r.member_tags ->> 'shop' = 'laundry'))) sr 345 | WHERE 346 | cs.osm_id = sr.member_id 347 | AND cs.osm_type = sr.member_type; 348 | 349 | -- sanitary_dump_station in site relations 350 | UPDATE 351 | osm_poi_campsites cs 352 | SET 353 | sanitary_dump_station = TRUE 354 | FROM ( 355 | SELECT 356 | s.member_id, 357 | s.member_type 358 | FROM 359 | osm_poi_camp_siterel_extended s 360 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 361 | AND s.member_tags ->> 'tourism' = 'camp_site' 362 | AND r.member_tags ->> 'amenity' = 'sanitary_dump_station') sr 363 | WHERE 364 | cs.osm_id = sr.member_id 365 | AND cs.osm_type = sr.member_type; 366 | 367 | -- firepit in site relations 368 | UPDATE 369 | osm_poi_campsites cs 370 | SET 371 | firepit = TRUE 372 | FROM ( 373 | SELECT 374 | s.member_id, 375 | s.member_type 376 | FROM 377 | osm_poi_camp_siterel_extended s 378 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 379 | AND s.member_tags ->> 'tourism' = 'camp_site' 380 | AND r.member_tags ->> 'leisure' = 'firepit') sr 381 | WHERE 382 | cs.osm_id = sr.member_id 383 | AND cs.osm_type = sr.member_type; 384 | 385 | -- bbq in site relations 386 | UPDATE 387 | osm_poi_campsites cs 388 | SET 389 | bbq = TRUE 390 | FROM ( 391 | SELECT 392 | s.member_id, 393 | s.member_type 394 | FROM 395 | osm_poi_camp_siterel_extended s 396 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 397 | AND s.member_tags ->> 'tourism' = 'camp_site' 398 | AND r.member_tags ->> 'amenity' = 'bbq') sr 399 | WHERE 400 | cs.osm_id = sr.member_id 401 | AND cs.osm_type = sr.member_type; 402 | 403 | -- toilets in site relations 404 | UPDATE 405 | osm_poi_campsites cs 406 | SET 407 | toilets = TRUE 408 | FROM ( 409 | SELECT 410 | s.member_id, 411 | s.member_type 412 | FROM 413 | osm_poi_camp_siterel_extended s 414 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 415 | AND s.member_tags ->> 'tourism' = 'camp_site' 416 | AND r.member_tags ->> 'amenity' = 'toilets') sr 417 | WHERE 418 | cs.osm_id = sr.member_id 419 | AND cs.osm_type = sr.member_type; 420 | 421 | -- showers or toilets with shower != 'no' in site relations 422 | UPDATE 423 | osm_poi_campsites cs 424 | SET 425 | shower = 'yes' 426 | FROM ( 427 | SELECT 428 | s.member_id, 429 | s.member_type 430 | FROM 431 | osm_poi_camp_siterel_extended s 432 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 433 | AND s.member_tags ->> 'tourism' = 'camp_site' 434 | AND ((r.member_tags ->> 'amenity' = 'shower') 435 | OR ((r.member_tags ->> 'amenity' = 'toilets') 436 | AND (r.member_tags ? 'shower') 437 | AND (r.member_tags ->> 'shower' != 'no')))) sr 438 | WHERE 439 | cs.osm_id = sr.member_id 440 | AND cs.osm_type = sr.member_type; 441 | 442 | -- showers with hot_water=no 443 | UPDATE 444 | osm_poi_campsites cs 445 | SET 446 | shower = 'cold' 447 | FROM ( 448 | SELECT 449 | s.member_id, 450 | s.member_type 451 | FROM 452 | osm_poi_camp_siterel_extended s 453 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 454 | AND s.member_tags ->> 'tourism' = 'camp_site' 455 | AND ((r.member_tags ->> 'amenity' = 'shower') 456 | AND (r.member_tags ->> 'hot_water' = 'no'))) sr 457 | WHERE 458 | cs.osm_id = sr.member_id 459 | AND cs.osm_type = sr.member_type; 460 | 461 | -- showers with hot_water=yes 462 | UPDATE 463 | osm_poi_campsites cs 464 | SET 465 | shower = 'hot' 466 | FROM ( 467 | SELECT 468 | s.member_id, 469 | s.member_type 470 | FROM 471 | osm_poi_camp_siterel_extended s 472 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 473 | AND s.member_tags ->> 'tourism' = 'camp_site' 474 | AND ((r.member_tags ->> 'amenity' = 'shower') 475 | AND (r.member_tags ->> 'hot_water' = 'yes'))) sr 476 | WHERE 477 | cs.osm_id = sr.member_id 478 | AND cs.osm_type = sr.member_type; 479 | 480 | -- playground in site relations 481 | UPDATE 482 | osm_poi_campsites cs 483 | SET 484 | playground = TRUE 485 | FROM ( 486 | SELECT 487 | s.member_id, 488 | s.member_type 489 | FROM 490 | osm_poi_camp_siterel_extended s 491 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 492 | AND s.member_tags ->> 'tourism' = 'camp_site' 493 | AND r.member_tags ->> 'leisure' = 'playground') sr 494 | WHERE 495 | cs.osm_id = sr.member_id 496 | AND cs.osm_type = sr.member_type; 497 | 498 | -- swimming_pool in site relations 499 | UPDATE 500 | osm_poi_campsites cs 501 | SET 502 | swimming_pool = TRUE 503 | FROM ( 504 | SELECT 505 | s.member_id, 506 | s.member_type 507 | FROM 508 | osm_poi_camp_siterel_extended s 509 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 510 | AND s.member_tags ->> 'tourism' = 'camp_site' 511 | AND r.member_tags ->> 'leisure' = 'swimming_pool') sr 512 | WHERE 513 | cs.osm_id = sr.member_id 514 | AND cs.osm_type = sr.member_type; 515 | 516 | -- golf_course in site relations 517 | UPDATE 518 | osm_poi_campsites cs 519 | SET 520 | golf_course = TRUE 521 | FROM ( 522 | SELECT 523 | s.member_id, 524 | s.member_type 525 | FROM 526 | osm_poi_camp_siterel_extended s 527 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 528 | AND s.member_tags ->> 'tourism' = 'camp_site' 529 | AND r.member_tags ->> 'leisure' = 'golf_course') sr 530 | WHERE 531 | cs.osm_id = sr.member_id 532 | AND cs.osm_type = sr.member_type; 533 | 534 | -- miniature_golf in site relations 535 | UPDATE 536 | osm_poi_campsites cs 537 | SET 538 | miniature_golf = TRUE 539 | FROM ( 540 | SELECT 541 | s.member_id, 542 | s.member_type 543 | FROM 544 | osm_poi_camp_siterel_extended s 545 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 546 | AND s.member_tags ->> 'tourism' = 'camp_site' 547 | AND r.member_tags ->> 'leisure' = 'miniature_golf') sr 548 | WHERE 549 | cs.osm_id = sr.member_id 550 | AND cs.osm_type = sr.member_type; 551 | 552 | -- sauna in site relations 553 | UPDATE 554 | osm_poi_campsites cs 555 | SET 556 | sauna = TRUE 557 | FROM ( 558 | SELECT 559 | s.member_id, 560 | s.member_type 561 | FROM 562 | osm_poi_camp_siterel_extended s 563 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 564 | AND s.member_tags ->> 'tourism' = 'camp_site' 565 | AND r.member_tags ->> 'leisure' = 'sauna') sr 566 | WHERE 567 | cs.osm_id = sr.member_id 568 | AND cs.osm_type = sr.member_type; 569 | 570 | -- fast_food in site relations 571 | UPDATE 572 | osm_poi_campsites cs 573 | SET 574 | fast_food = TRUE 575 | FROM ( 576 | SELECT 577 | s.member_id, 578 | s.member_type 579 | FROM 580 | osm_poi_camp_siterel_extended s 581 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 582 | AND s.member_tags ->> 'tourism' = 'camp_site' 583 | AND r.member_tags ->> 'amenity' = 'fast_food') sr 584 | WHERE 585 | cs.osm_id = sr.member_id 586 | AND cs.osm_type = sr.member_type; 587 | 588 | -- restaurant in site relations 589 | UPDATE 590 | osm_poi_campsites cs 591 | SET 592 | restaurant = TRUE 593 | FROM ( 594 | SELECT 595 | s.member_id, 596 | s.member_type 597 | FROM 598 | osm_poi_camp_siterel_extended s 599 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 600 | AND s.member_tags ->> 'tourism' = 'camp_site' 601 | AND r.member_tags ->> 'amenity' = 'restaurant') sr 602 | WHERE 603 | cs.osm_id = sr.member_id 604 | AND cs.osm_type = sr.member_type; 605 | 606 | -- pub in site relations 607 | UPDATE 608 | osm_poi_campsites cs 609 | SET 610 | pub = TRUE 611 | FROM ( 612 | SELECT 613 | s.member_id, 614 | s.member_type 615 | FROM 616 | osm_poi_camp_siterel_extended s 617 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 618 | AND s.member_tags ->> 'tourism' = 'camp_site' 619 | AND r.member_tags ->> 'amenity' = 'pub') sr 620 | WHERE 621 | cs.osm_id = sr.member_id 622 | AND cs.osm_type = sr.member_type; 623 | 624 | -- bar in site relations 625 | UPDATE 626 | osm_poi_campsites cs 627 | SET 628 | bar = TRUE 629 | FROM ( 630 | SELECT 631 | s.member_id, 632 | s.member_type 633 | FROM 634 | osm_poi_camp_siterel_extended s 635 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 636 | AND s.member_tags ->> 'tourism' = 'camp_site' 637 | AND r.member_tags ->> 'amenity' = 'bar') sr 638 | WHERE 639 | cs.osm_id = sr.member_id 640 | AND cs.osm_type = sr.member_type; 641 | 642 | -- sports facilities in site relations 643 | UPDATE 644 | osm_poi_campsites cs 645 | SET 646 | sport = ARRAY ( SELECT DISTINCT 647 | UNNEST(cs.sport || sr.sport)) 648 | FROM ( 649 | SELECT 650 | s.member_id, 651 | s.member_type, 652 | array_agg(r.member_tags ->> 'sport') AS sport 653 | FROM 654 | osm_poi_camp_siterel_extended s 655 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 656 | AND s.member_tags ->> 'tourism' = 'camp_site' 657 | AND r.member_tags ? 'sport' 658 | GROUP BY 659 | s.member_id, 660 | s.member_type) sr 661 | WHERE 662 | cs.osm_id = sr.member_id 663 | AND cs.osm_type = sr.member_type; 664 | 665 | -- Add site relation URL to member campsites 666 | UPDATE 667 | osm_poi_campsites cs 668 | SET 669 | -- This will overwrite the site_relation value with the latter one, 670 | -- if the site is a member of more than one site relation 671 | tags = tags || jsonb_build_object('site_relation', sr.site_id::text) 672 | FROM ( 673 | SELECT 674 | member_id, 675 | member_type, 676 | site_id 677 | FROM 678 | osm_poi_camp_siterel_extended 679 | WHERE 680 | member_tags ->> 'tourism' = 'camp_site') sr 681 | WHERE 682 | cs.osm_id = sr.member_id 683 | AND cs.osm_type = sr.member_type; 684 | 685 | -- Mark campsites which are members of an invalid site relation 686 | -- with more than one member tagged 'tourism' = 'camp_site' 687 | UPDATE 688 | osm_poi_campsites cs 689 | SET 690 | tags = tags || jsonb_build_object('site_relation_state', 'invalid') 691 | FROM ( 692 | SELECT 693 | member_id, 694 | member_type 695 | FROM 696 | osm_poi_camp_siterel_extended 697 | WHERE 698 | site_id IN ( 699 | SELECT 700 | site_id 701 | FROM ( 702 | SELECT 703 | site_id, 704 | count(*) 705 | FROM 706 | osm_poi_camp_siterel_extended 707 | WHERE 708 | member_tags ->> 'tourism' = 'camp_site' 709 | GROUP BY 710 | site_id) AS c 711 | WHERE 712 | COUNT != 1) 713 | AND member_tags ->> 'tourism' = 'camp_site') sr 714 | WHERE 715 | cs.osm_id = sr.member_id 716 | AND cs.osm_type = sr.member_type; 717 | 718 | -- Mark campsites which are members of a redundant site relation 719 | -- with all POI objects inside the 'tourism' = 'camp_site' polygon 720 | UPDATE 721 | osm_poi_campsites cs 722 | SET 723 | tags = tags || jsonb_build_object('site_relation_state', 'useless') 724 | FROM ( 725 | SELECT 726 | s.member_id, 727 | bool_and(st_within (r.geom, s.geom)) AS WITHIN 728 | FROM 729 | osm_poi_camp_siterel_extended s 730 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 731 | AND s.member_tags ->> 'tourism' = 'camp_site' 732 | AND ((r.member_tags ->> 'tourism' != 'camp_site') 733 | OR NOT (r.member_tags ? 'tourism')) 734 | GROUP BY 735 | s.member_id) sr 736 | WHERE 737 | sr.within = TRUE 738 | AND cs.osm_id = sr.member_id; 739 | 740 | 741 | 742 | 743 | 744 | COMMIT; 745 | 746 | DELETE FROM osm_todo_campsites; 747 | DELETE FROM osm_todo_cs_trigger; 748 | DELETE FROM osm_todo_camp_siterel; 749 | 750 | -- Finally remove all stuff where tagging has changed form 'camp_site' or 'caravan_site' 751 | -- to something else because these are then no longer camp-sites 752 | DELETE FROM osm_poi_campsites WHERE tags->>'tourism' NOT IN ('camp_site', 'caravan_site'); 753 | 754 | 755 | -- Post update stuff for TABLE osm_poi_playgrounds 756 | 757 | -- This will insert all playgrounds which are affected by other POI updates 758 | INSERT INTO osm_todo_playgrounds(osm_id,osm_type,is_pg) 759 | SELECT pa.osm_id,pa.osm_type,true 760 | FROM osm_poi_all pa, 761 | ( 762 | SELECT pa.osm_type,pa.osm_id,pa.geom 763 | FROM osm_poi_all pa 764 | JOIN osm_todo_playgrounds tp 765 | ON tp.osm_id=pa.osm_id AND tp.osm_type=pa.osm_type 766 | WHERE tp.is_pg=false 767 | ) as tp 768 | WHERE (pa.tags ->> 'leisure' = 'playground') 769 | AND ST_Intersects(tp.geom,pa.geom) 770 | ON CONFLICT (osm_id,osm_type) DO NOTHING; 771 | 772 | DELETE FROM osm_todo_playgrounds WHERE is_pg=false; 773 | 774 | INSERT INTO osm_todo_playgrounds(osm_id,osm_type,is_pg) 775 | SELECT osm_id,osm_type,true 776 | FROM osm_todo_pg_trigger 777 | ON CONFLICT (osm_id,osm_type) DO NOTHING; 778 | 779 | BEGIN; 780 | DELETE FROM osm_poi_playgrounds 781 | USING osm_todo_playgrounds 782 | WHERE osm_poi_playgrounds.osm_id = osm_todo_playgrounds.osm_id 783 | AND osm_poi_playgrounds.osm_type = osm_todo_playgrounds.osm_type; 784 | 785 | INSERT INTO osm_poi_playgrounds 786 | SELECT 787 | poly.osm_id AS osm_id, 788 | poly.osm_type AS osm_type, 789 | poly.tags AS tags, 790 | greatest(max(CASE WHEN _st_intersects(poly.geom, pt.geom) THEN pt.timestamp END),poly.timestamp) as timestamp, 791 | poly.geom AS geom, 792 | -- This will produce a list of available playground facilities on the premises 793 | array_remove(array_agg(DISTINCT CASE WHEN (_st_intersects (poly.geom, pt.geom) 794 | AND (pt.tags ? 'playground') 795 | AND (pt.osm_id != poly.osm_id)) THEN 796 | pt.tags ->> 'playground' 797 | END), NULL) AS equipment, 798 | -- This will produce a list of available sport facilities on the premises 799 | array_remove(array_agg(DISTINCT CASE WHEN (_st_intersects (poly.geom, pt.geom) 800 | AND (pt.tags ? 'sport') 801 | AND (pt.osm_id != poly.osm_id)) THEN 802 | pt.tags ->> 'sport' 803 | END), NULL) AS sport 804 | FROM 805 | osm_todo_playgrounds tp, 806 | osm_poi_poly AS poly 807 | LEFT JOIN osm_poi_ptpy AS pt ON poly.geom && pt.geom 808 | WHERE 809 | poly.osm_id=tp.osm_id AND poly.osm_type=tp.osm_type 810 | GROUP BY 811 | poly.osm_id, 812 | poly.osm_type, 813 | poly.tags, 814 | poly.timestamp, 815 | poly.geom 816 | UNION ALL 817 | SELECT 818 | pp.osm_id, 819 | pp.osm_type, 820 | pp.tags, 821 | pp.timestamp, 822 | pp.geom, 823 | '{}', 824 | '{}' 825 | FROM 826 | osm_todo_playgrounds tp, 827 | osm_poi_point pp 828 | WHERE pp.osm_id=tp.osm_id AND pp.osm_type=tp.osm_type; 829 | COMMIT; 830 | 831 | DELETE FROM osm_todo_playgrounds; 832 | DELETE FROM osm_todo_pg_trigger; 833 | 834 | -- Finally remove all stuff where tagging has changed form leisure=playground 835 | -- to something else because these are then no longer playgrounds 836 | DELETE FROM osm_poi_playgrounds WHERE NOT tags->>'leisure'='playground'; 837 | -------------------------------------------------------------------------------- /run-osm2pgsql-replication.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | if [ $# -eq 0 ]; then 4 | echo "usage: $(basename $0) basedir" 5 | exit 1 6 | fi 7 | 8 | DATA_DIR=${1}/data 9 | CODE_DIR=${1}/osmpoidb 10 | DBNAME='poi' 11 | 12 | set -e 13 | 14 | cd $CODE_DIR 15 | # in case something went wrong in previous cycle delete old stuff 16 | echo "DELETE FROM osm_todo_campsites; DELETE FROM osm_todo_cs_trigger;" |psql -q $DBNAME 17 | echo "DELETE FROM osm_todo_playgrounds; DELETE FROM osm_todo_pg_trigger;" |psql -q $DBNAME 18 | osm2pgsql-replication update -d $DBNAME --post-processing ./post-update.sh 19 | 20 | 21 | 22 | 23 | 24 | -------------------------------------------------------------------------------- /sitemap-index.cgi: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python 2 | # -*- coding: UTF-8 -*- 3 | # 4 | # Generate multilingual xml sitemaps for OpenCampingMap 5 | # 6 | # 7 | import psycopg2 8 | import re 9 | import os 10 | 11 | dbconnstr="dbname=poi" 12 | index_query = "SELECT distinct tags ->> 'addr:country' AS country,max(timestamp) as timestamp FROM osm_poi_campsites WHERE tags ? 'addr:country' AND visible = TRUE GROUP BY country;" 13 | 14 | sitemap_path = b"/sitemaps" 15 | 16 | # If another language is added to OpenCampingMap this template needs to be modified 17 | # as wenn as the code where it gets filled 18 | url_template = '''\t 19 | \t\t%s/en/%s/%d 20 | \t\t 21 | \t\t 22 | \t\t 23 | \t\t 24 | \t\t 25 | \t\t%s+00:00 26 | \t 27 | '''.encode() 28 | 29 | def gen404(path): 30 | status = '404 Not Found' 31 | headers = [('Content-type', 'text/html; charset=utf-8')] 32 | body=b'\n\n\n\nError\n\n\n
Cannot GET %s
\n\n\n' % path 33 | return status,headers,body 34 | 35 | def dbError(): 36 | status = '404 Not Found' 37 | headers = [('Content-type', 'text/html; charset=utf-8')] 38 | body=b'\n\n\n\nError\n\n\n
Unable to connect to database!
\n\n\n' 39 | return status,headers,body 40 | 41 | def genSiteMapIndex(conn,baseurl): 42 | status = '200 OK' 43 | headers = [('Content-type', 'text/xml')] 44 | body=b'\n\n' 45 | cur = conn.cursor() 46 | cur.execute(index_query) 47 | res = cur.fetchall() 48 | cur.close() 49 | for r in res: 50 | body=body+b'\t\n' 51 | body=body+b'\t\t%s/%s.xml\n' % (os.path.dirname(baseurl)+sitemap_path,r[0].encode()) 52 | body=body+b'\t\t%s+00:00\n' % r[1].isoformat().encode() 53 | body=body+b'\t\n' 54 | body=body+b'\n' 55 | conn.close() 56 | return status,headers,body 57 | 58 | def application(environ, start_response): 59 | dberror = False 60 | try: 61 | dbcon = psycopg2.connect(dbconnstr) 62 | except: 63 | dberror = True 64 | 65 | if dberror: 66 | status,headers,body = dbError() 67 | else: 68 | if environ['PATH_INFO'] == '': 69 | status,headers,body = genSiteMapIndex(dbcon,environ['SCRIPT_URI'].encode()) 70 | else: 71 | status,headers,body = gen404(bytes(environ['REQUEST_URI'],"utf-8")) 72 | start_response(status, headers) 73 | return [body] 74 | 75 | -------------------------------------------------------------------------------- /sitemaps.cgi: -------------------------------------------------------------------------------- 1 | #!/usr/bin/python 2 | # -*- coding: UTF-8 -*- 3 | # 4 | # Generate multilingual xml sitemaps for OpenCampingMap 5 | # 6 | # 7 | import psycopg2 8 | import re 9 | import os 10 | 11 | dbconnstr="dbname=poi" 12 | sitemap_query = "SELECT osm_type,osm_id,timestamp FROM osm_poi_campsites WHERE tags ->> 'addr:country' = '%s' AND tags ? 'name' AND visible = TRUE;" 13 | 14 | # If another language is added to OpenCampingMap this template needs to be modified 15 | # as wenn as the code where it gets filled 16 | url_template = '''\t 17 | \t\t%s/en/%s/%d 18 | \t\t 19 | \t\t 20 | \t\t 21 | \t\t 22 | \t\t 23 | \t\t%s+00:00 24 | \t 25 | '''.encode() 26 | 27 | osm_type = {'N':b'node','W':b'way','R':b'relation'} 28 | 29 | def gen404(path): 30 | status = '404 Not Found' 31 | headers = [('Content-type', 'text/html; charset=utf-8')] 32 | body=b'\n\n\n\nError\n\n\n
Cannot GET %s
\n\n\n' % path 33 | return status,headers,body 34 | 35 | def dbError(): 36 | status = '404 Not Found' 37 | headers = [('Content-type', 'text/html; charset=utf-8')] 38 | body=b'\n\n\n\nError\n\n\n
Unable to connect to database!
\n\n\n' 39 | return status,headers,body 40 | 41 | def genSiteMap(conn,baseurl,country): 42 | status = '200 OK' 43 | headers = [('Content-type', 'text/xml')] 44 | body = b'\n\n' 46 | cur = conn.cursor('smc') 47 | cur.execute(sitemap_query % country) 48 | res = cur.fetchall() 49 | # this construction seems to be faster than a for loop 50 | #body += b"".join([b'\t\n\t\t%s/en/%s/%d\n\t\t%s+00:00\n\t\n' % (baseurl,osm_type[r[0]],r[1],r[2].isoformat().encode()) for r in res]) 51 | body += b"".join([url_template % (baseurl,osm_type[r[0]],r[1],baseurl,osm_type[r[0]],r[1],baseurl,osm_type[r[0]],r[1],baseurl,osm_type[r[0]],r[1],baseurl,osm_type[r[0]],r[1],baseurl,osm_type[r[0]],r[1],r[2].isoformat().encode()) for r in res]) 52 | body += b'\n' 53 | cur.close() 54 | conn.close() 55 | return status,headers,body 56 | 57 | def application(environ, start_response): 58 | dberror = False 59 | try: 60 | dbcon = psycopg2.connect(dbconnstr) 61 | except: 62 | dberror = True 63 | 64 | if dberror: 65 | status,headers,body = dbError() 66 | else: 67 | if re.match("^/[a-z][a-z].xml$",environ['PATH_INFO']): 68 | status,headers,body = genSiteMap(dbcon,os.path.dirname(os.path.dirname(environ['SCRIPT_URI'])).encode(),environ['PATH_INFO'][1:3]) 69 | else: 70 | status,headers,body = gen404(bytes(environ['REQUEST_URI'],"utf-8")) 71 | start_response(status, headers) 72 | return [body] 73 | 74 | -------------------------------------------------------------------------------- /update-poi-campsites-from-siterel.sql: -------------------------------------------------------------------------------- 1 | -- update table osm_poi_campsites based on members of site relations 2 | -- 3 | -- (c) 2021 Sven Geggus 4 | -- 5 | -- Changes made here might also need to be added to gen_poi_campsites.sql 6 | -- 7 | -- merge tags from site relation itself into tags from related point or polygon 8 | -- tagged as 'tourism'='camp_site' 9 | -- this will prefer the tags from the site relation over the ones from the point or polygon 10 | 11 | UPDATE 12 | osm_poi_campsites cs 13 | SET 14 | -- ignore addr:country from site relation 15 | tags = cs.tags || (sr.site_tags - 'type'::text - 'site'::text - 'addr:country'::text) 16 | FROM ( 17 | SELECT 18 | member_id, 19 | member_type, 20 | site_tags 21 | FROM 22 | osm_poi_camp_siterel_extended 23 | WHERE 24 | member_tags ->> 'tourism' = 'camp_site') sr 25 | WHERE 26 | cs.osm_id = sr.member_id 27 | AND cs.osm_type = sr.member_type; 28 | 29 | -- telephone in site relations 30 | UPDATE 31 | osm_poi_campsites cs 32 | SET 33 | telephone = TRUE 34 | FROM ( 35 | SELECT 36 | s.member_id, 37 | s.member_type 38 | FROM 39 | osm_poi_camp_siterel_extended s 40 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 41 | AND s.member_tags ->> 'tourism' = 'camp_site' 42 | AND r.member_tags ->> 'amenity' = 'telephone') sr 43 | WHERE 44 | cs.osm_id = sr.member_id 45 | AND cs.osm_type = sr.member_type; 46 | 47 | -- post_box in site relations 48 | UPDATE 49 | osm_poi_campsites cs 50 | SET 51 | post_box = TRUE 52 | FROM ( 53 | SELECT 54 | s.member_id, 55 | s.member_type 56 | FROM 57 | osm_poi_camp_siterel_extended s 58 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 59 | AND s.member_tags ->> 'tourism' = 'camp_site' 60 | AND r.member_tags ->> 'amenity' = 'post_box') sr 61 | WHERE 62 | cs.osm_id = sr.member_id 63 | AND cs.osm_type = sr.member_type; 64 | 65 | -- drinking_water in site relations 66 | UPDATE 67 | osm_poi_campsites cs 68 | SET 69 | drinking_water = TRUE 70 | FROM ( 71 | SELECT 72 | s.member_id, 73 | s.member_type 74 | FROM 75 | osm_poi_camp_siterel_extended s 76 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 77 | AND s.member_tags ->> 'tourism' = 'camp_site' 78 | AND r.member_tags ->> 'amenity' = 'drinking_water') sr 79 | WHERE 80 | cs.osm_id = sr.member_id 81 | AND cs.osm_type = sr.member_type; 82 | 83 | -- any shop (likely convenience) in site relations 84 | UPDATE 85 | osm_poi_campsites cs 86 | SET 87 | shop = TRUE 88 | FROM ( 89 | SELECT 90 | s.member_id, 91 | s.member_type 92 | FROM 93 | osm_poi_camp_siterel_extended s 94 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 95 | AND s.member_tags ->> 'tourism' = 'camp_site' 96 | AND (r.member_tags ? 'shop' 97 | AND r.member_tags ->> 'shop' != 'laundry')) sr 98 | WHERE 99 | cs.osm_id = sr.member_id 100 | AND cs.osm_type = sr.member_type; 101 | 102 | -- laundry or washing machine in site relations 103 | UPDATE 104 | osm_poi_campsites cs 105 | SET 106 | laundry = TRUE 107 | FROM ( 108 | SELECT 109 | s.member_id, 110 | s.member_type 111 | FROM 112 | osm_poi_camp_siterel_extended s 113 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 114 | AND s.member_tags ->> 'tourism' = 'camp_site' 115 | AND ((r.member_tags ->> 'amenity' = 'washing_machine') 116 | OR (r.member_tags ->> 'shop' = 'laundry'))) sr 117 | WHERE 118 | cs.osm_id = sr.member_id 119 | AND cs.osm_type = sr.member_type; 120 | 121 | -- sanitary_dump_station in site relations 122 | UPDATE 123 | osm_poi_campsites cs 124 | SET 125 | sanitary_dump_station = TRUE 126 | FROM ( 127 | SELECT 128 | s.member_id, 129 | s.member_type 130 | FROM 131 | osm_poi_camp_siterel_extended s 132 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 133 | AND s.member_tags ->> 'tourism' = 'camp_site' 134 | AND r.member_tags ->> 'amenity' = 'sanitary_dump_station') sr 135 | WHERE 136 | cs.osm_id = sr.member_id 137 | AND cs.osm_type = sr.member_type; 138 | 139 | -- firepit in site relations 140 | UPDATE 141 | osm_poi_campsites cs 142 | SET 143 | firepit = TRUE 144 | FROM ( 145 | SELECT 146 | s.member_id, 147 | s.member_type 148 | FROM 149 | osm_poi_camp_siterel_extended s 150 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 151 | AND s.member_tags ->> 'tourism' = 'camp_site' 152 | AND r.member_tags ->> 'leisure' = 'firepit') sr 153 | WHERE 154 | cs.osm_id = sr.member_id 155 | AND cs.osm_type = sr.member_type; 156 | 157 | -- bbq in site relations 158 | UPDATE 159 | osm_poi_campsites cs 160 | SET 161 | bbq = TRUE 162 | FROM ( 163 | SELECT 164 | s.member_id, 165 | s.member_type 166 | FROM 167 | osm_poi_camp_siterel_extended s 168 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 169 | AND s.member_tags ->> 'tourism' = 'camp_site' 170 | AND ((r.member_tags ->> 'amenity' = 'bbq') 171 | OR ((r.member_tags ->> 'leisure' = 'firepit') 172 | AND (r.member_tags ? 'grate') 173 | AND (r.member_tags ->> 'grate' = 'yes')))) sr 174 | WHERE 175 | cs.osm_id = sr.member_id 176 | AND cs.osm_type = sr.member_type; 177 | 178 | -- toilets in site relations 179 | UPDATE 180 | osm_poi_campsites cs 181 | SET 182 | toilets = TRUE 183 | FROM ( 184 | SELECT 185 | s.member_id, 186 | s.member_type 187 | FROM 188 | osm_poi_camp_siterel_extended s 189 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 190 | AND s.member_tags ->> 'tourism' = 'camp_site' 191 | AND r.member_tags ->> 'amenity' = 'toilets') sr 192 | WHERE 193 | cs.osm_id = sr.member_id 194 | AND cs.osm_type = sr.member_type; 195 | 196 | -- showers or toilets with shower tag in site relations 197 | UPDATE 198 | osm_poi_campsites cs 199 | SET 200 | shower = showertype 201 | FROM ( 202 | SELECT 203 | s.member_id, 204 | s.member_type, 205 | MIN( 206 | CASE 207 | WHEN (r.member_tags ->> 'amenity' = 'shower') AND r.member_tags ->> 'hot_water' = 'yes' then 'hot'::showertype 208 | WHEN (r.member_tags ->> 'amenity' = 'toilets') AND r.member_tags ->> 'shower' = 'hot' then 'hot'::showertype 209 | WHEN (r.member_tags ->> 'amenity' = 'shower') AND r.member_tags ->> 'hot_water' = 'no' then 'cold'::showertype 210 | WHEN (r.member_tags ->> 'amenity' = 'toilets') AND r.member_tags ->> 'shower' = 'cold' then 'cold'::showertype 211 | WHEN (r.member_tags ->> 'amenity' = 'shower') AND NOT ( r.member_tags ? 'hot_water') then 'yes'::showertype 212 | WHEN (r.member_tags ->> 'amenity' = 'toilets') AND r.member_tags ->> 'shower' = 'yes' then 'yes'::showertype 213 | WHEN (s.member_tags ->> 'shower' = 'hot') then 'hot'::showertype 214 | WHEN (s.member_tags ->> 'shower' = 'cold') then 'cold'::showertype 215 | WHEN (s.member_tags ->> 'shower' = 'yes') then 'yes'::showertype 216 | WHEN (s.member_tags ->> 'shower' = 'outdoor') then 'yes'::showertype 217 | WHEN (s.member_tags ->> 'shower' = 'no') then 'no'::showertype 218 | ELSE 'untagged'::showertype END 219 | ) as showertype 220 | FROM 221 | osm_poi_camp_siterel_extended s 222 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 223 | AND s.member_tags ->> 'tourism' = 'camp_site' 224 | AND ((r.member_tags ->> 'amenity' = 'shower') 225 | OR ((r.member_tags ->> 'amenity' = 'toilets') 226 | AND (r.member_tags ? 'shower'))) GROUP BY s.member_id,s.member_type) sr 227 | WHERE 228 | cs.osm_id = sr.member_id 229 | AND cs.osm_type = sr.member_type; 230 | 231 | -- playground in site relations 232 | UPDATE 233 | osm_poi_campsites cs 234 | SET 235 | playground = TRUE 236 | FROM ( 237 | SELECT 238 | s.member_id, 239 | s.member_type 240 | FROM 241 | osm_poi_camp_siterel_extended s 242 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 243 | AND s.member_tags ->> 'tourism' = 'camp_site' 244 | AND r.member_tags ->> 'leisure' = 'playground') sr 245 | WHERE 246 | cs.osm_id = sr.member_id 247 | AND cs.osm_type = sr.member_type; 248 | 249 | -- swimming_pool in site relations 250 | UPDATE 251 | osm_poi_campsites cs 252 | SET 253 | swimming_pool = TRUE 254 | FROM ( 255 | SELECT 256 | s.member_id, 257 | s.member_type 258 | FROM 259 | osm_poi_camp_siterel_extended s 260 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 261 | AND s.member_tags ->> 'tourism' = 'camp_site' 262 | AND r.member_tags ->> 'leisure' = 'swimming_pool') sr 263 | WHERE 264 | cs.osm_id = sr.member_id 265 | AND cs.osm_type = sr.member_type; 266 | 267 | -- golf_course in site relations 268 | UPDATE 269 | osm_poi_campsites cs 270 | SET 271 | golf_course = TRUE 272 | FROM ( 273 | SELECT 274 | s.member_id, 275 | s.member_type 276 | FROM 277 | osm_poi_camp_siterel_extended s 278 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 279 | AND s.member_tags ->> 'tourism' = 'camp_site' 280 | AND r.member_tags ->> 'leisure' = 'golf_course') sr 281 | WHERE 282 | cs.osm_id = sr.member_id 283 | AND cs.osm_type = sr.member_type; 284 | 285 | -- miniature_golf in site relations 286 | UPDATE 287 | osm_poi_campsites cs 288 | SET 289 | miniature_golf = TRUE 290 | FROM ( 291 | SELECT 292 | s.member_id, 293 | s.member_type 294 | FROM 295 | osm_poi_camp_siterel_extended s 296 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 297 | AND s.member_tags ->> 'tourism' = 'camp_site' 298 | AND r.member_tags ->> 'leisure' = 'miniature_golf') sr 299 | WHERE 300 | cs.osm_id = sr.member_id 301 | AND cs.osm_type = sr.member_type; 302 | 303 | -- sauna in site relations 304 | UPDATE 305 | osm_poi_campsites cs 306 | SET 307 | sauna = TRUE 308 | FROM ( 309 | SELECT 310 | s.member_id, 311 | s.member_type 312 | FROM 313 | osm_poi_camp_siterel_extended s 314 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 315 | AND s.member_tags ->> 'tourism' = 'camp_site' 316 | AND r.member_tags ->> 'leisure' = 'sauna') sr 317 | WHERE 318 | cs.osm_id = sr.member_id 319 | AND cs.osm_type = sr.member_type; 320 | 321 | -- fast_food in site relations 322 | UPDATE 323 | osm_poi_campsites cs 324 | SET 325 | fast_food = TRUE 326 | FROM ( 327 | SELECT 328 | s.member_id, 329 | s.member_type 330 | FROM 331 | osm_poi_camp_siterel_extended s 332 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 333 | AND s.member_tags ->> 'tourism' = 'camp_site' 334 | AND r.member_tags ->> 'amenity' = 'fast_food') sr 335 | WHERE 336 | cs.osm_id = sr.member_id 337 | AND cs.osm_type = sr.member_type; 338 | 339 | -- restaurant in site relations 340 | UPDATE 341 | osm_poi_campsites cs 342 | SET 343 | restaurant = TRUE 344 | FROM ( 345 | SELECT 346 | s.member_id, 347 | s.member_type 348 | FROM 349 | osm_poi_camp_siterel_extended s 350 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 351 | AND s.member_tags ->> 'tourism' = 'camp_site' 352 | AND r.member_tags ->> 'amenity' = 'restaurant') sr 353 | WHERE 354 | cs.osm_id = sr.member_id 355 | AND cs.osm_type = sr.member_type; 356 | 357 | -- pub in site relations 358 | UPDATE 359 | osm_poi_campsites cs 360 | SET 361 | pub = TRUE 362 | FROM ( 363 | SELECT 364 | s.member_id, 365 | s.member_type 366 | FROM 367 | osm_poi_camp_siterel_extended s 368 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 369 | AND s.member_tags ->> 'tourism' = 'camp_site' 370 | AND r.member_tags ->> 'amenity' = 'pub') sr 371 | WHERE 372 | cs.osm_id = sr.member_id 373 | AND cs.osm_type = sr.member_type; 374 | 375 | -- bar in site relations 376 | UPDATE 377 | osm_poi_campsites cs 378 | SET 379 | bar = TRUE 380 | FROM ( 381 | SELECT 382 | s.member_id, 383 | s.member_type 384 | FROM 385 | osm_poi_camp_siterel_extended s 386 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 387 | AND s.member_tags ->> 'tourism' = 'camp_site' 388 | AND r.member_tags ->> 'amenity' = 'bar') sr 389 | WHERE 390 | cs.osm_id = sr.member_id 391 | AND cs.osm_type = sr.member_type; 392 | 393 | -- kitchen in site relations 394 | UPDATE 395 | osm_poi_campsites cs 396 | SET 397 | bar = TRUE 398 | FROM ( 399 | SELECT 400 | s.member_id, 401 | s.member_type 402 | FROM 403 | osm_poi_camp_siterel_extended s 404 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 405 | AND s.member_tags ->> 'tourism' = 'camp_site' 406 | AND r.member_tags ->> 'amenity' = 'kitchen') sr 407 | WHERE 408 | cs.osm_id = sr.member_id 409 | AND cs.osm_type = sr.member_type; 410 | 411 | 412 | -- sinks or kitchen with sink != 'no' in site relations 413 | UPDATE 414 | osm_poi_campsites cs 415 | SET 416 | sink = TRUE 417 | FROM ( 418 | SELECT 419 | s.member_id, 420 | s.member_type 421 | FROM 422 | osm_poi_camp_siterel_extended s 423 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 424 | AND s.member_tags ->> 'tourism' = 'camp_site' 425 | AND ((r.member_tags ->> 'amenity' = 'sink') 426 | OR ((r.member_tags ->> 'amenity' = 'kitchen') 427 | AND (r.member_tags ? 'sink') 428 | AND (r.member_tags ->> 'sink' != 'no')))) sr 429 | WHERE 430 | cs.osm_id = sr.member_id 431 | AND cs.osm_type = sr.member_type; 432 | 433 | -- fridges or kitchen with fridge != 'no' in site relations 434 | UPDATE 435 | osm_poi_campsites cs 436 | SET 437 | fridge = TRUE 438 | FROM ( 439 | SELECT 440 | s.member_id, 441 | s.member_type 442 | FROM 443 | osm_poi_camp_siterel_extended s 444 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 445 | AND s.member_tags ->> 'tourism' = 'camp_site' 446 | AND ((r.member_tags ->> 'amenity' = 'fridge') 447 | OR ((r.member_tags ->> 'amenity' = 'kitchen') 448 | AND (r.member_tags ? 'fridge') 449 | AND (r.member_tags ->> 'fridge' != 'no')))) sr 450 | WHERE 451 | cs.osm_id = sr.member_id 452 | AND cs.osm_type = sr.member_type; 453 | 454 | -- picnic_table in site relations 455 | UPDATE 456 | osm_poi_campsites cs 457 | SET 458 | bar = TRUE 459 | FROM ( 460 | SELECT 461 | s.member_id, 462 | s.member_type 463 | FROM 464 | osm_poi_camp_siterel_extended s 465 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 466 | AND s.member_tags ->> 'tourism' = 'camp_site' 467 | AND r.member_tags ->> 'amenity' = 'picnic_table') sr 468 | WHERE 469 | cs.osm_id = sr.member_id 470 | AND cs.osm_type = sr.member_type; 471 | 472 | -- sports facilities in site relations 473 | UPDATE 474 | osm_poi_campsites cs 475 | SET 476 | sport = ARRAY ( SELECT DISTINCT 477 | UNNEST(cs.sport || sr.sport)) 478 | FROM ( 479 | SELECT 480 | s.member_id, 481 | s.member_type, 482 | array_agg(r.member_tags ->> 'sport') AS sport 483 | FROM 484 | osm_poi_camp_siterel_extended s 485 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 486 | AND s.member_tags ->> 'tourism' = 'camp_site' 487 | AND r.member_tags ? 'sport' 488 | GROUP BY 489 | s.member_id, 490 | s.member_type) sr 491 | WHERE 492 | cs.osm_id = sr.member_id 493 | AND cs.osm_type = sr.member_type; 494 | 495 | -- Add site relation URL to member campsites 496 | UPDATE 497 | osm_poi_campsites cs 498 | SET 499 | -- This will overwrite the site_relation value with the latter one, 500 | -- if the site is a member of more than one site relation 501 | tags = tags || jsonb_build_object('site_relation', sr.site_id::text) 502 | FROM ( 503 | SELECT 504 | member_id, 505 | member_type, 506 | site_id 507 | FROM 508 | osm_poi_camp_siterel_extended 509 | WHERE 510 | member_tags ->> 'tourism' = 'camp_site') sr 511 | WHERE 512 | cs.osm_id = sr.member_id 513 | AND cs.osm_type = sr.member_type; 514 | 515 | -- Mark campsites which are members of an invalid site relation 516 | -- with more than one member tagged 'tourism' = 'camp_site' 517 | UPDATE 518 | osm_poi_campsites cs 519 | SET 520 | tags = tags || jsonb_build_object('site_relation_state', 'invalid') 521 | FROM ( 522 | SELECT 523 | member_id, 524 | member_type 525 | FROM 526 | osm_poi_camp_siterel_extended 527 | WHERE 528 | site_id IN ( 529 | SELECT 530 | site_id 531 | FROM ( 532 | SELECT 533 | site_id, 534 | count(*) 535 | FROM 536 | osm_poi_camp_siterel_extended 537 | WHERE 538 | member_tags ->> 'tourism' = 'camp_site' 539 | GROUP BY 540 | site_id) AS c 541 | WHERE 542 | COUNT != 1) 543 | AND member_tags ->> 'tourism' = 'camp_site') sr 544 | WHERE 545 | cs.osm_id = sr.member_id 546 | AND cs.osm_type = sr.member_type; 547 | 548 | -- Mark campsites which are members of a redundant site relation 549 | -- with all POI objects inside the 'tourism' = 'camp_site' polygon 550 | UPDATE 551 | osm_poi_campsites cs 552 | SET 553 | tags = tags || jsonb_build_object('site_relation_state', 'useless') 554 | FROM ( 555 | SELECT 556 | s.member_id, 557 | bool_and(st_within (r.geom, s.geom)) AS WITHIN 558 | FROM 559 | osm_poi_camp_siterel_extended s 560 | INNER JOIN osm_poi_camp_siterel_extended r ON s.site_id = r.site_id 561 | AND s.member_tags ->> 'tourism' = 'camp_site' 562 | AND ((r.member_tags ->> 'tourism' != 'camp_site') 563 | OR NOT (r.member_tags ? 'tourism')) 564 | GROUP BY 565 | s.member_id) sr 566 | WHERE 567 | sr.within = TRUE 568 | AND cs.osm_id = sr.member_id; 569 | 570 | -------------------------------------------------------------------------------- /update-poi-campsites-with-bugs.sql: -------------------------------------------------------------------------------- 1 | -- update osm_poi_campsites with obvious bugs to display them on Open Camping Map 2 | -- 3 | -- (c) 2022-2024 Sven Geggus 4 | -- 5 | -- tourism=camp_site objects inside tourism=camp_site objects 6 | -- are obviously bugs, so both types need to be marked. 7 | -- 8 | -- 9 | 10 | BEGIN; 11 | 12 | -- First remove old markers 13 | UPDATE osm_poi_campsites SET tags = tags - 'contains_sites' WHERE tags ? 'contains_sites'; 14 | 15 | -- Now mark campsites that contain others 16 | UPDATE 17 | osm_poi_campsites cs 18 | SET 19 | tags = tags || jsonb_build_object('contains_sites', si.urls_inner) 20 | FROM ( 21 | SELECT 22 | o.osm_id AS id_outer, 23 | o.osm_type AS type_outer, 24 | string_agg('https://osm.org/' || CASE WHEN i.osm_type = 'W' THEN 'way/' WHEN i.osm_type = 'N' THEN 'node/' ELSE 'relation/' END || i.osm_id::text, ' ') AS urls_inner 25 | FROM 26 | osm_poi_campsites o, 27 | osm_poi_campsites i 28 | WHERE 29 | st_contains (o.geom, i.geom) 30 | AND o.osm_id != i.osm_id 31 | AND (i.tags ->> 'tourism' != 'caravan_site') 32 | GROUP BY 33 | o.osm_id, 34 | o.osm_type) si 35 | WHERE 36 | si.id_outer = cs.osm_id 37 | AND si.type_outer = cs.osm_type; 38 | 39 | -- First mark all objects as visible 40 | UPDATE osm_poi_campsites SET visible = TRUE; 41 | 42 | -- 43 | -- Now mark campsites and caravan sites that are inside others as invisible 44 | -- 45 | -- 46 | UPDATE 47 | osm_poi_campsites cs 48 | SET 49 | visible = FALSE 50 | FROM ( 51 | SELECT 52 | i.osm_id AS id_inner, 53 | i.osm_type AS type_inner 54 | FROM 55 | osm_poi_campsites o, 56 | osm_poi_campsites i 57 | WHERE 58 | st_contains (o.geom, i.geom) 59 | AND o.osm_id != i.osm_id 60 | GROUP BY 61 | i.osm_id, 62 | i.osm_type) sc 63 | WHERE 64 | sc.id_inner = cs.osm_id 65 | AND sc.type_inner = cs.osm_type; 66 | 67 | COMMIT; 68 | --------------------------------------------------------------------------------