From d3dee22bc2f24c6b70bdada1665c2bfc118fac19 Mon Sep 17 00:00:00 2001 From: Pete Kauss Date: Sun, 23 Feb 2020 16:12:07 +0000 Subject: [PATCH] issue #20, itens 1 e 2 --- README.md | 7 +- Rationale.md => docs/Rationale.md | 0 src/README.md | 9 ++- src/prepare01-2.sh | 3 +- src/prepare02-1-libPub.sql | 14 ++++ src/prepare02-2-danger.sql | 79 +++++++++++++++++++ ...{prepare02-lib.sql => prepare02-3-lib.sql} | 64 ++++----------- ...ets.sql => prepare03-loadDatasetsOnce.sql} | 0 src/prepare04-danger.sql | 32 +------- 9 files changed, 125 insertions(+), 83 deletions(-) rename Rationale.md => docs/Rationale.md (100%) create mode 100644 src/prepare02-1-libPub.sql create mode 100644 src/prepare02-2-danger.sql rename src/{prepare02-lib.sql => prepare02-3-lib.sql} (87%) rename src/{prepare03-loadDatasets.sql => prepare03-loadDatasetsOnce.sql} (100%) diff --git a/README.md b/README.md index 3dcbc77..689c94d 100644 --- a/README.md +++ b/README.md @@ -1,10 +1,11 @@ ## Stable -Projeto em quarententa, aguardando aprovação da comunidade. Neste período estaremos discutindo tudo em https://github.com/OSMBrasil/stable/issues +Projeto em quarententa, aguardando aprovação da comunidade. +Neste período estaremos discutindo tudo em https://github.com/OSMBrasil/stable/issues Para auditoria da origem dos dados ou ingestão de novos, ver [`brazil-latest.osm.md`](brazil-latest.osm.md#dump-opensstreetmap-do-brasil). -Para auditoria ou reprodução passo-a-passo do processamento em base de dados SQL, +Para auditoria ou reprodução passo-a-passo do processamento em base de dados SQL, ver pasta [**src**](src/README.md#software-de-gestão-do-repositório-stable-br). Para justificativas de decisões de projeto, -ver [Rationale.md](Rationale.md). +ver [Rationale.md](docs/Rationale.md). Para verificar um exemplo de dados estáveis, ver por exemplo [PR-Curitiba](PR-Curitiba). diff --git a/Rationale.md b/docs/Rationale.md similarity index 100% rename from Rationale.md rename to docs/Rationale.md diff --git a/src/README.md b/src/README.md index 4a41f5a..fcfa5c6 100644 --- a/src/README.md +++ b/src/README.md @@ -1,11 +1,16 @@ ## Software de gestão do repositório Stable-BR O presente repositório, *git OSM-Stable-BR* (URL canônica [`git.openStreetMap.org.br/stable`](https://github.com/OSMBrasil/stable)), -tem sua origem no gerenciamento de dados realizado por diversos _softwares_, tendo como principais na sua infraestrutura PostgreSQL, PostGIS, Osm2pgsql ([refs](#Referências)). +tem sua origem no gerenciamento de dados realizado por diversos _softwares_, +tendo como principais na sua infraestrutura PostgreSQL, PostGIS, Osm2pgsql ([refs](#Referências)). Para usar todos os scrits desta pasta, sugere-se iniciar pelo *git clone* do repositório. Os scripts bash [prepare01-1.sh](prepare01-1.sh) e [prepare01-2.sh](prepare01-2.sh) devem rodar em sequência. -O software SQL necessário é instalado a partir de [prepare02-lib.sql](prepare02-lib.sql) e [prepare03-loadDatasets.sql](prepare03-loadDatasets.sql). +HowTo-cityGeoJSON.md prepare01-1.sh prepare02-1-libPub.sql prepare02-3-lib.sql prepare03-loadDatasetsOnce.sql +README.md prepare01-2.sh prepare02-2-danger.sql prepare02-lib-StableFuncsOriginal.sql prepare04-danger.sql + +O software SQL necessário é instalado a partir de [prepare02-1-libPub.sql](prepare02-1-libPub.sql), +tomandose o cuidado de não rodar mais do que uma vez arquivos sufixo "danger" ou "Once", `prepare*-danger.sql`. ## Tutorial passo-a-passo Passo a passo para fazer carga ou manutenção do *git OSM-Stable-BR*. diff --git a/src/prepare01-2.sh b/src/prepare01-2.sh index 742676c..a347cb8 100644 --- a/src/prepare01-2.sh +++ b/src/prepare01-2.sh @@ -12,7 +12,8 @@ wget -O /tmp/br_city_codes.csv -c https://raw.githubusercontent.com/datasets-b wget -O /tmp/br-region-codes.csv -c https://raw.githubusercontent.com/datasets-br/state-codes/master/data/br-region-codes.csv wget -O /tmp/br-state-codes.csv -c https://raw.githubusercontent.com/datasets-br/state-codes/master/data/br-state-codes.csv -psql postgres://postgres:myPass@localhost/osm_stable_br < ./prepare02-lib.sql +psql postgres://postgres:myPass@localhost/osm_stable_br < prepare02-1-libPub.sql +psql postgres://postgres:myPass@localhost/osm_stable_br < prepare02-2-lib.sql echo ' -- Para o próximo passo melhor rodar em BAT (com & no final), vai demorar... copie e cole:' diff --git a/src/prepare02-1-libPub.sql b/src/prepare02-1-libPub.sql new file mode 100644 index 0000000..8a35891 --- /dev/null +++ b/src/prepare02-1-libPub.sql @@ -0,0 +1,14 @@ + +CREATE or replace FUNCTION jsonb_strip_nulls_v2( + p_input jsonb +) RETURNS jsonb AS $f$ + SELECT CASE WHEN x='{}'::JSONb THEN NULL ELSE x END FROM (SELECT jsonb_strip_nulls($1)) t(x) +$f$ LANGUAGE SQL IMMUTABLE; + + +DROP AGGREGATE IF EXISTS array_agg_cat(anyarray) CASCADE; +CREATE AGGREGATE array_agg_cat(anyarray) ( + SFUNC=array_cat, + STYPE=anyarray, + INITCOND='{}' +); diff --git a/src/prepare02-2-danger.sql b/src/prepare02-2-danger.sql new file mode 100644 index 0000000..7d925b6 --- /dev/null +++ b/src/prepare02-2-danger.sql @@ -0,0 +1,79 @@ +DROP TABLE IF EXISTS stable.member_of CASCADE; +CREATE TABLE stable.member_of( + osm_owner bigint NOT NULL, -- osm_id of a relations + osm_type char(1) NOT NULL, -- from split + osm_id bigint NOT NULL, -- from split + member_type text, + UNIQUE(osm_owner, osm_type, osm_id) +); +CREATE INDEX stb_member_idx ON stable.member_of(osm_type, osm_id); + +--- + +CREATE or replace FUNCTION stable.osm_to_jsonb_remove() RETURNS text[] AS $f$ + SELECT array['osm_uid','osm_user','osm_version','osm_changeset','osm_timestamp']; +$f$ LANGUAGE SQL IMMUTABLE; + +CREATE FUNCTION stable.osm_to_jsonb( + p_input text[], p_strip boolean DEFAULT false +) RETURNS jsonb AS $f$ + SELECT CASE WHEN p_strip THEN jsonb_strip_nulls_v2(x) ELSE x END + FROM ( + SELECT jsonb_object($1) - stable.osm_to_jsonb_remove() + ) t(x) +$f$ LANGUAGE sql IMMUTABLE; + +CREATE FUNCTION stable.osm_to_jsonb( + p_input public.hstore, p_strip boolean DEFAULT false +) RETURNS jsonb AS $f$ + SELECT CASE WHEN p_strip THEN jsonb_strip_nulls_v2(x) ELSE x END + FROM ( + SELECT hstore_to_jsonb_loose($1) - stable.osm_to_jsonb_remove() + ) t(x) +$f$ LANGUAGE sql IMMUTABLE; + +/*lixo old +CREATE or replace FUNCTION stable.osm_to_jsonb(text[]) RETURNS JSONb AS $f$ + SELECT jsonb_object($1) - stable.osm_to_jsonb_remove() +$f$ LANGUAGE SQL IMMUTABLE; + +CREATE or replace FUNCTION stable.osm_to_jsonb(hstore) RETURNS JSONb AS $f$ + SELECT hstore_to_jsonb_loose($1) - stable.osm_to_jsonb_remove() +$f$ LANGUAGE SQL IMMUTABLE; +*/ + +------------ + +ALTER TABLE planet_osm_rels alter column members + type jsonb USING jsonb_object(members) +; -- fazer o com update até estar seguro. Depois trocar por stable.osmmembers_pack(jsonb_object(members)); + +-- demora 15 min: +ALTER TABLE planet_osm_line alter column tags type jsonb USING stable.osm_to_jsonb(tags); +ALTER TABLE planet_osm_ways alter column tags type jsonb + USING jsonb_strip_nulls_v2(stable.osm_to_jsonb(tags)); -- ~10 min + +-- mais rapidos: +ALTER TABLE planet_osm_polygon alter column tags type jsonb USING stable.osm_to_jsonb(tags); +ALTER TABLE planet_osm_rels alter column tags type jsonb USING stable.osm_to_jsonb(tags); + + +-- Opcional LIXO: +/* deu pau, anulando 'name:' ... revisar depois quando for usar. +UPDATE planet_osm_polygon -- ~10 minutos. 4.396.944 linhas. + SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); +UPDATE planet_osm_line -- ~9 minutos. 3.869.230 linhas + SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); +UPDATE planet_osm_rels -- ~1 minuto. 151.288 linhas + SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); +*/ + +UPDATE planet_osm_polygon + SET tags = jsonb_strip_nulls_v2(tags); +UPDATE planet_osm_line + SET tags = jsonb_strip_nulls_v2(tags); +UPDATE planet_osm_rels + SET tags = jsonb_strip_nulls_v2(tags); + + +-- carrega 02-3-lib e CONTINUA N0 04 diff --git a/src/prepare02-lib.sql b/src/prepare02-3-lib.sql similarity index 87% rename from src/prepare02-lib.sql rename to src/prepare02-3-lib.sql index 7fccd34..00cce07 100644 --- a/src/prepare02-lib.sql +++ b/src/prepare02-3-lib.sql @@ -26,14 +26,7 @@ INSERT INTO stable.element_exists(is_node,osm_id) SELECT true,id FROM planet_osm_nodes; */ -CREATE TABLE stable.member_of( - osm_owner bigint NOT NULL, -- osm_id of a relations - osm_type char(1) NOT NULL, -- from split - osm_id bigint NOT NULL, -- from split - member_type text, - UNIQUE(osm_owner, osm_type, osm_id) -); -CREATE INDEX stb_member_idx ON stable.member_of(osm_type, osm_id); + CREATE or replace FUNCTION stable.members_pack( p_owner_id bigint -- osm_id of a relation @@ -72,10 +65,6 @@ CREATE or replace FUNCTION stable.lexname_to_path( $f$ LANGUAGE SQL IMMUTABLE; -CREATE or replace FUNCTION stable.osm_to_jsonb_remove() RETURNS text[] AS $f$ - SELECT array['osm_uid','osm_user','osm_version','osm_changeset','osm_timestamp']; -$f$ LANGUAGE SQL IMMUTABLE; - CREATE or replace FUNCTION stable.osm_to_jsonb_remove_prefix( jsonb,text default 'name:' ) RETURNS text[] AS $f$ @@ -99,32 +88,7 @@ CREATE or replace FUNCTION stable.tags_split_prefix( )) $f$ LANGUAGE SQL IMMUTABLE; -CREATE or replace FUNCTION stable.osm_to_jsonb(text[]) RETURNS JSONb AS $f$ - SELECT jsonb_object($1) - stable.osm_to_jsonb_remove() -$f$ LANGUAGE SQL IMMUTABLE; - -CREATE or replace FUNCTION stable.osm_to_jsonb(hstore) RETURNS JSONb AS $f$ - SELECT hstore_to_jsonb_loose($1) - stable.osm_to_jsonb_remove() -$f$ LANGUAGE SQL IMMUTABLE; -CREATE or replace FUNCTION stable.member_md5key( - p_members jsonb, -- input from planet_osm_rels - p_no_rel boolean DEFAULT false, -- exclude rel-members - p_w_char char DEFAULT 'w' -- or '' for hexadecimal output. -) RETURNS text AS $f$ - SELECT p_w_char || COALESCE($1->>'w_md5','') || CASE - WHEN p_no_rel THEN '' - ELSE 'r' || COALESCE($1->>'r_md5','') - END -$f$ LANGUAGE SQL IMMUTABLE; - -CREATE or replace FUNCTION stable.member_md5key( - p_rel_id bigint, - p_no_rel boolean DEFAULT false -- exclude rel-members -) RETURNS text AS $f$ - SELECT stable.member_md5key(members,p_no_rel) - FROM planet_osm_rels WHERE id=p_rel_id -$f$ LANGUAGE SQL IMMUTABLE; /* select count(*) from (select stable.member_md5key(members,true) g, count(*) from planet_osm_rels group by 1 having count(*)>1) t; -- = 4761 @@ -156,7 +120,7 @@ $f$ LANGUAGE SQL IMMUTABLE; --- -DROP TABLE IF EXISTS stable.city_test_names; +DROP TABLE IF EXISTS stable.city_test_names CASCADE; CREATE TABLE stable.city_test_names AS SELECT unnest( '{PR/Curitiba,PR/MarechalCandidoRondon,SC/JaraguaSul,SP/MonteiroLobato,MG/SantaCruzMinas,SP/SaoPaulo,PA/Altamira,RJ/AngraReis}'::text[] @@ -165,6 +129,13 @@ CREATE TABLE stable.city_test_names AS ----- +CREATE or replace FUNCTION stable.rel_properties(p_osm_id bigint) RETURNS jsonb AS $f$ + SELECT tags || jsonb_build_object('members',members) + FROM planet_osm_rels r + WHERE id = abs(p_osm_id) +$f$ LANGUAGE sql IMMUTABLE; + + CREATE or replace FUNCTION stable.rel_dup_properties( p_osm_id bigint, p_osm_type char, @@ -244,20 +215,19 @@ CREATE or replace FUNCTION stable.rel_properties( WHERE id = abs(p_osm_id) $f$ LANGUAGE SQL IMMUTABLE; + CREATE or replace FUNCTION stable.way_properties( - p_osm_id bigint -) RETURNS JSONb AS $f$ + p_osm_id bigint +) RETURNS jsonb AS $f$ SELECT tags || jsonb_build_object( 'nodes',nodes, 'nodes_md5',LPAD(to_hex(nodes_md5_int),16,'0') - ) || COALESCE( - select from rels! - stable.rel_dup_properties(id,'w',nodes_md5_int,nodes), - '{}'::jsonb - ) + ) -- || COALESCE( + -- select from rels! stable.rel_dup_properties(id,'w',nodes_md5_int,nodes) limit 1 + -- ,'{}'::jsonb ) FROM planet_osm_ways r WHERE id = p_osm_id -$f$ LANGUAGE SQL IMMUTABLE; +$f$ LANGUAGE sql IMMUTABLE; CREATE or replace FUNCTION stable.element_properties( p_osm_id bigint, @@ -274,7 +244,7 @@ $wrap$ LANGUAGE SQL IMMUTABLE; * Use ST_AsGeoJSONb( geom, 6, 1, osm_id::text, stable.element_properties(osm_id) - 'name:' ). */ CREATE or replace FUNCTION ST_AsGeoJSONb( -- ST_AsGeoJSON_complete - st_asgeojsonb(geometry, integer, integer, bigint, jsonb + -- st_asgeojsonb(geometry, integer, integer, bigint, jsonb p_geom geometry, p_decimals int default 6, p_options int default 1, -- 1=better (implicit WGS84) tham 5 (explicit) diff --git a/src/prepare03-loadDatasets.sql b/src/prepare03-loadDatasetsOnce.sql similarity index 100% rename from src/prepare03-loadDatasets.sql rename to src/prepare03-loadDatasetsOnce.sql diff --git a/src/prepare04-danger.sql b/src/prepare04-danger.sql index ad71fa1..72b4072 100644 --- a/src/prepare04-danger.sql +++ b/src/prepare04-danger.sql @@ -1,35 +1,8 @@ -ALTER TABLE planet_osm_rels alter column members - type jsonb USING jsonb_object(members) -; -- fazer o com update até estar seguro. Depois trocar por stable.osmmembers_pack(jsonb_object(members)); UPDATE planet_osm_rels SET members=COALESCE(stable.members_pack(id), members); --- demora 15 min: -ALTER TABLE planet_osm_line alter column tags type jsonb USING stable.osm_to_jsonb(tags); -ALTER TABLE planet_osm_ways alter column tags type jsonb - USING jsonb_strip_nulls_v2(stable.osm_to_jsonb(tags)); -- ~10 min - --- mais rapidos: -ALTER TABLE planet_osm_polygon alter column tags type jsonb USING stable.osm_to_jsonb(tags); -ALTER TABLE planet_osm_rels alter column tags type jsonb USING stable.osm_to_jsonb(tags); - - --- Opcional: -/* deu pau, anulando 'name:' ... revisar depois quando for usar. -UPDATE planet_osm_polygon -- ~10 minutos. 4.396.944 linhas. - SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); -UPDATE planet_osm_line -- ~9 minutos. 3.869.230 linhas - SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); -UPDATE planet_osm_rels -- ~1 minuto. 151.288 linhas - SET tags = stable.tags_split_prefix(jsonb_strip_nulls_v2(tags)); -*/ -UPDATE planet_osm_polygon - SET tags = jsonb_strip_nulls_v2(tags); -UPDATE planet_osm_line - SET tags = jsonb_strip_nulls_v2(tags); -UPDATE planet_osm_rels - SET tags = jsonb_strip_nulls_v2(tags); +---- CREATE or replace FUNCTION stable.getcity_rels_id( p_cod_ibge text -- código IBGE do município, wikidata-id, lex-name ou path-name @@ -59,7 +32,7 @@ CREATE or replace FUNCTION stable.getcity_rels_id( SELECT stable.getcity_rels_id($1::text,$2) $wrap$ LANGUAGE SQL IMMUTABLE; -/*- - +/*- - LIXO SELECT ibge_id, stable.getcity_rels_id(ibge_id) osm_id FROM brcodes_city; select stable.getcity_rels_id('4304408'); @@ -89,7 +62,6 @@ CREATE or replace FUNCTION stable.getcity_line_geom( $f$ LANGUAGE SQL IMMUTABLE; - -------- -- script para rodar em BAT: