├── aux_files ├── MER_cnefe2010.pdf └── test_queries_for_osm_setorCensitario_intersection.sql ├── SC_screenshots ├── SC_multiple_blocks.PNG ├── SC_half_block_example.PNG ├── SC_half_block_in_CNEFE.PNG ├── SC_multiple_blocks_in_CNEFE.PNG └── SC_displocated_EDs_from_undelying_OSM-Streets_Salvador.PNG ├── README.md ├── Examples_of_SC_vs_OSM.md ├── OSM_Streets_SetorCensitario_spatial_match.sql ├── Import_data.md ├── temp_older_code.txt └── OMS_and_CNEFE_blocks_matching.sql /aux_files/MER_cnefe2010.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/aux_files/MER_cnefe2010.pdf -------------------------------------------------------------------------------- /SC_screenshots/SC_multiple_blocks.PNG: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/SC_screenshots/SC_multiple_blocks.PNG -------------------------------------------------------------------------------- /SC_screenshots/SC_half_block_example.PNG: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/SC_screenshots/SC_half_block_example.PNG -------------------------------------------------------------------------------- /SC_screenshots/SC_half_block_in_CNEFE.PNG: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/SC_screenshots/SC_half_block_in_CNEFE.PNG -------------------------------------------------------------------------------- /SC_screenshots/SC_multiple_blocks_in_CNEFE.PNG: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/SC_screenshots/SC_multiple_blocks_in_CNEFE.PNG -------------------------------------------------------------------------------- /SC_screenshots/SC_displocated_EDs_from_undelying_OSM-Streets_Salvador.PNG: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/lucasmation/osm_cnefe_import/HEAD/SC_screenshots/SC_displocated_EDs_from_undelying_OSM-Streets_Salvador.PNG -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | osm_cnefe_import 2 | ================ 3 | 4 | This project aims to mactch the national address cadaster from 2010 Census of Brazil (CNEFE) to Opeen Street Map and evaluate the possibility of an import. 5 | 6 | Objectives: 7 | 1) Finding Street names for unanmed streets in OSM-Brazil 8 | 2) Matching named Street Segments in OSM-Brazi to the corresponding Street Segments in CNEFE to add the adress informatoin, present in CNEFE. 9 | 10 | Matching theses data is not trivial, requiring serveral normalizations, spatial transformations, matches, etc. 11 | 12 | This requires setting up a Linux machine with PostGIS (I used Ubuntu 12.04, with PostgreSQL 9.3 and PostGis 2.1). 13 | 14 | The file import_data.md describes how to import the data main datasets. 15 | 16 | Bellow we describe the dataest and how to transform them for objectives 1 and 2. 17 | 18 | 19 | ## Data description 20 | 21 | ### CNEFE data 22 | 23 | 24 | ### OSM data 25 | 26 | Datasets and the project are described at this OSM Wiki: 27 | 28 | http://wiki.openstreetmap.org/wiki/CNEFE_data,_IBGE,_Brasil_import 29 | 30 | 31 | 32 | ## 1) Finding Street names for unanmed streets in OSM-Brazil 33 | 34 | to be done 35 | 36 | ## 2) Matching named street segments in OSM and CNEFE 37 | 38 | This is a difficult problem because CNEFE does not contain geometric features of roads (or city blocks). The most spatially precise geometries that can be attributed to CNEFE are the Enumeration Districts (setores censitarios) areas which can comprize of about 8 blocks). 39 | 40 | However, each address in CNEFE contains a "city block code". Thus, it is possible to aggregate CNEFE into a dataset of city blocks, characterized by their surounding streets. With some SQL magic, OSM data can also be aggregated into a similar city block datasey with souringing streets for each block. Therefore, as long as street names are the same in the two datasets, OSM and CNEFE city blocks can be matched. 41 | 42 | The code at OMS_and_CNEFE_blocks_matching.sql does that 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | -------------------------------------------------------------------------------- /Examples_of_SC_vs_OSM.md: -------------------------------------------------------------------------------- 1 | 2 | This page illustrates how the Enumeration Districts (ED, Setor Censitario) polygons relate to OSM streets. 3 | 4 | Bellow: 5 | - Enumeration Districts = Green 6 | - OSM streets a= red 7 | 8 | Enumeration Districts are defined to contain 250-350 households, respecting, as best as possible, street boundaries. Thus, the EDs size depends on how dense areas are. In a lower density area, with mostly larger houses, an ED can span serveral city blocks. In a denselly populated area, dominated by apartment buildings, an ED can take only a block, or even less. 9 | 10 | This is reflected in CNEFE, where household addresses are indexed by "city block" and "city block face" codes, which are subdivisions of EDs. 11 | 12 | 13 | The images bellow describes some of theese cases. 14 | Theese images are from the municipality of Sao Paulo -SP, where geometries of EDs and OSM-Streets are somewhat consistent (in other areas they can be quite inconsistent) 15 | 16 | 17 | 18 | ## Case 1: ED spans several blocks (most common case) 19 | 20 | ED-polygos vs OSM-Streets: 21 | 22 | ![alt tag](SC_screenshots/SC_multiple_blocks.PNG) 23 | 24 | REPRESENTATION in CNEFE: 25 | 26 | ![alt tag](SC_screenshots/SC_multiple_blocks_in_CNEFE.PNG) 27 | 28 | 29 | 30 | ## Case 2: ED spans lest than one block (denser areas) 31 | 32 | ED-polygos vs OSM-Streets: 33 | 34 | ![alt tag](SC_screenshots/SC_half_block_example.PNG) 35 | 36 | REPRESENTATION in CNEFE: 37 | 38 | ![alt tag](SC_screenshots/SC_half_block_in_CNEFE.PNG) 39 | 40 | 41 | ## Case 3: ED polygons are displocated 42 | 43 | This exaple is from downtown Salvador 44 | 45 | ![alt tag](SC_screenshots/SC_displocated_EDs_from_undelying_OSM-Streets_Salvador.PNG) 46 | 47 | Notice how the ED polygons are dislocated notheast from the undelying OSM-Streets (suposebly the "true" location). 48 | A person at OSM-dev IRC suggested that the projection for the ED layer may be wrong. Maybe it could actualy be SAD69 (4618) instead of the recorded SIRGAS2000 (4674). I tryed to Update_GeometrySRID() but that did not work (as documented in [this gis.stackexchange question](http://gis.stackexchange.com/questions/154389/updating-srid-update-geometrysrid-does-not-alter-polygons-when-it-should)) 49 | 50 | 51 | 52 | 53 | 54 | -------------------------------------------------------------------------------- /OSM_Streets_SetorCensitario_spatial_match.sql: -------------------------------------------------------------------------------- 1 | 2 | --Mathcing osm_streets to Setor Censitario Polygons. 3 | -- Because Setor Censitario polygons can have some problems, shifted sideways, etc, I used a 0.0005 decimal degrees buffer (+or- 56m) around the polygons 4 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 5 | SELECT osm_id, cd_geocodi as cod_setor 6 | FROM OSM_Streets_by_mun 7 | INNER JOIN setor_censitarioL2 8 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 9 | ST_DWithin(way,geom,0.0005); 10 | -- runs in 1h36 11 | 12 | 13 | 14 | --------------------------------------------- 15 | 16 | 17 | select* from OSM_Streets_by_SetorCensitario limit 2000 18 | 19 | create table OSM_Streets_by_SetorCensitario AS SELECT * from OSM_Streets_by_SetorCensitarioA 20 | drop table OSM_Streets_by_SetorCensitarioA 21 | 22 | SELECT N, count(*) 23 | FROM 24 | (SELECT osm_id, count(*) as N 25 | FROM OSM_Streets_by_SetorCensitario 26 | GROUP BY osm_id) AS foo 27 | GROUP BY N 28 | ORDER BY count(*) desc 29 | 30 | 31 | 32 | Re run with smaller buffer. 33 | 34 | 35 | 36 | 37 | 38 | --Experimenting with different buffers (based on code baed on G) = Matching with municipal code and ST_DWithin 39 | 40 | EXPLAIN 41 | create table OSM_Streets_by_SetorCensitario_005 as select * from OSM_Streets_by_SetorCensitario 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | select count(*) from OSM_Streets_by_SetorCensitario -- 5116195 50 | -- eliminando duplicatas sao 5044154 51 | 52 | 53 | 54 | CREATE TABLE sectors_by_osm_id AS 55 | SELECT osm_id, count(*) AS No_setores, array_agg(cod_setor) 56 | FROM ( select osm_id , cod_setor , count(*) AS N from OSM_Streets_by_SetorCensitario 57 | group by osm_id , cod_setor ) AS foo 58 | GROUP BY osm_id 59 | 60 | select No_setores, count(*) 61 | from sectors_by_osm_id 62 | group by No_setores 63 | order by count(*) desc 64 | 65 | select * from sectors_by_osm_id limit 2000-- 5116195 66 | 67 | select * from OSM_Streets_by_SetorCensitario limit 2000-- 5116195 68 | 69 | 70 | -- 5.1 million rows, 1h37min. Query returned successfully: 5116195 rows affected, 5822001 ms execution time. 71 | 72 | -- To do latter Even better will be to have the buffer proportional to the distortion found in each street (by matching OSM to CNEFE and selecting fcnefe sectors with all blocks mateched)) 73 | 74 | 75 | 76 | 77 | -- grouping OSM-streets by setor 78 | select substring(cod_setor,1,7) AS cod_mun, osm_id, count(cod_setor) as N_setores, array_agg(cod_setor) 79 | FROM OSM_Streets_by_SetorCensitario 80 | GROUP BY substring(cod_setor,1,7), osm_id 81 | 82 | select * from setor_censitarioL2 limit 2000 83 | 84 | 85 | drop table temp3 86 | 87 | 88 | -- agregate CNEFE streets by setor 89 | CREATE TABLE temp3 AS 90 | SELECT substring(cod_setor,1,7) AS cod_mun, logradouro.idn_logradouro, 91 | tipo_logradouro.dsc_tipo_logradouro, logradouro.dsc_titulo_logradouro, logradouro.nme_logradouro, 92 | trim(concat_ws(' ',tipo_logradouro.dsc_tipo_logradouro,logradouro.dsc_titulo_logradouro,logradouro.nme_logradouro)) AS nomeC_logradouro, 93 | array_agg(cod_setor), ST_Union(geom) AS geom 94 | FROM cnefe2010.setor 95 | INNER JOIN setor_censitarioL2 96 | ON substring(setor.cod_setor,1,7) = setor_censitarioL2.cd_geocodm 97 | INNER JOIN cnefe2010.quadra 98 | ON cnefe2010.setor.idn_setor = cnefe2010.quadra.idn_setor 99 | INNER JOIN cnefe2010.face 100 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 101 | INNER JOIN cnefe2010.face_tem_logradouros 102 | ON cnefe2010.face.idn_face = cnefe2010.face_tem_logradouros.idn_face 103 | INNER JOIN cnefe2010.logradouro 104 | ON cnefe2010.face_tem_logradouros.idn_logradouro=cnefe2010.logradouro.idn_logradouro 105 | INNER JOIN cnefe2010.tipo_logradouro 106 | ON cnefe2010.logradouro.idn_tipo_logradouro = cnefe2010.tipo_logradouro.idn_tipo_logradouro 107 | WHERE substring(cod_setor, 1,7) = '3550308' 108 | GROUP BY substring(cod_setor,1,7), logradouro.idn_logradouro, 109 | tipo_logradouro.dsc_tipo_logradouro, logradouro.dsc_titulo_logradouro, logradouro.nme_logradouro, 110 | nomeC_logradouro 111 | 112 | -- select only streets that are matched to setors that are countigous 113 | 114 | SELECT ST_GeometryType(geom), count(*) 115 | from temp3 116 | GROUP BY ST_GeometryType(geom) 117 | ORDER BY count(*) desc 118 | 119 | 120 | 121 | 122 | 123 | HAVING ST_Union(geom) 124 | 125 | 126 | 127 | -------------------------------------------------------------------------------- /Import_data.md: -------------------------------------------------------------------------------- 1 | ###Preparing the machine and importing data 2 | 3 | Scripts to prepare CNEFE data, on street names and addresses in Brasil, to be imported/integrated into Opeen Street Map 4 | 5 | Commands bellow are to be run from a Linux Terminal 6 | 7 | ###Preparing the machine 8 | Install Postgresql and PostGIS flowing this totorial: http://switch2osm.org/loading-osm-data/ 9 | 10 | ``` 11 | mkdir ~/osm_cnefe_import 12 | ``` 13 | ###Creating Database 14 | ``` 15 | sudo -u postgres createuser -s $USER 16 | createdb osm_cnefe_import 17 | psql -d osm_cnefe_import -c 'CREATE EXTENSION hstore; CREATE EXTENSION postgis;' 18 | ``` 19 | 20 | 21 | 22 | ###Importing CNEFE data: 23 | Still incomplete. Just some references bellow 24 | 25 | Downloading the data: 26 | ``` 27 | mkdir ~/osm_cnefe_import/CNEFE 28 | cd ~/osm_cnefe_import/CNEFE 29 | wget -r -nd --read-timeout=5 ftp://ftp.ibge.gov.br/Censos/Censo_Demografico_2010/Cadastro_Nacional_de_Enderecos_Fins_Estatisticos/ 30 | unzip '*.zip' 31 | ``` 32 | obs: downloading will take some time, there are 10904 files totaling 926Mb 33 | 34 | Now we can follow two strategies: 35 | 36 | #### Importing with pgloader 37 | 38 | haven't tryed yet, could not find a tutorial including pgloader in a multiple files to one table setting. 39 | 40 | #### Importing with psql \copy command 41 | 42 | This is based on [this sugestion](http://www.postgresonline.com/journal/archives/157-Import-fixed-width-data-into-PostgreSQL-with-just-psql.html) to use only psql \copy command, import as a text blob to a staging table in Postgres and parse the content of each colum in Postgres. To deal with the several files to be imported I'm using the suggestion in [this StackOverflow quetion](http://stackoverflow.com/questions/12646305/efficient-way-to-import-a-lot-of-csv-files-into-postgresql-db), of creating a creating an import file with one copy command perCNEFE file. 43 | 44 | This may also be usefull (depois tirar): http://postgresql.nabble.com/Multiple-COPY-statements-td5701101.html 45 | 46 | 47 | Creating an import file with one copy command perCNEFE file. 48 | 49 | ``` 50 | (for FILE in ./*.TXT; do echo "\COPY cnefe_staging FROM '$FILE'"; done) > temp_CNEFE_import-commands.sql 51 | ``` 52 | 53 | Correcting Encoding: 54 | when importing the oringinal unzipped files into Postgres I encountered encoding problems ("psql:temp_CNEFE_import-commands.sql:1: ERROR: invalid byte sequence for encoding "UTF8": 0xe9 0x63 0x69 55 | CONTEXT: COPY cnefe_staging, line 452" similar for command 6, line 6538). I solved this with the 'recode' package: 56 | ``` 57 | sudo apt-get install recode 58 | recode iso-8859-1..utf8 *.TXT 59 | ``` 60 | 61 | Importing to a table in Postgres 62 | ``` 63 | psql -d osm_cnefe_import -c 'DROP TABLE cnefe_staging'; 64 | psql -d osm_cnefe_import -c 'CREATE TABLE cnefe_staging (data text)' 65 | psql -d osm_cnefe_import -f temp_CNEFE_import-commands.sql 66 | ``` 67 | about 70 milion rows (it should have 84 milion) 68 | 69 | 70 | Even with the above "recode" I'm still getting the the following encode errors: 71 | " 72 | psql:temp_CNEFE_import-commands.sql:8346: ERROR: invalid byte sequence for encoding "UTF8": 0xc2 0x20 73 | CONTEXT: COPY cnefe_staging, line 49070: "42 4202 5 0 1781TRAVESSA TAILANDIA ..." 74 | psql:temp_CNEFE_import-commands.sql:9189: ERROR: invalid byte sequence for encoding "UTF8": 0x94 75 | CONTEXT: COPY cnefe_staging, line 1023: "43 9100 5 0 21AVENIDA BORGES DE MEDEIROS ..." 76 | psql:temp_CNEFE_import-commands.sql:10794: ERROR: invalid byte sequence for encoding "UTF8": 0x00 77 | CONTEXT: COPY cnefe_staging, line 10418: "5215702 5 0 391RUA TREZE ..." 78 | " 79 | 80 | 81 | Separating fields 82 | ``` 83 | psql -d osm_cnefe_import -f create_cnefe_unnormalized.sql 84 | ``` 85 | osb: see the create_cnefe_unnormalized.sql in this gihub repo. 86 | Table is created but I get an error: 87 | "CREATE TABLE 88 | psql:create_cnefe_unnormalized.sql:84: ERROR: invalid input syntax for integer: " 89 | 90 | nada é adicionado à tabela 91 | 92 | next tings to do: 93 | 94 | create the CNEFE table, separating the fields from the stagging table 95 | 96 | add indexes 97 | 98 | normalize the CNEFE table into the tables: roads, enumeration districts, addresses, localidades 99 | 100 | add the geoms of the enumeration districts 101 | 102 | 103 | 104 | ###Importing polygons of Setores Censitarios (enumeration districts): 105 | Downloading the data: 106 | ``` 107 | mkdir ~/osm_cnefe_import/set_censitario 108 | cd ~/osm_cnefe_import/set_censitario 109 | wget -r -nd ftp://geoftp.ibge.gov.br/malhas_digitais/censo_2010/setores_censitarios/ 110 | unzip '*.zip' 111 | cp -p $(find . -name *SEE250GC_SIR.*) . 112 | rm -r */ 113 | ``` 114 | 115 | Importing into Postgresql: 116 | ``` 117 | shp2pgsql -c -s 4674:4326 -I -W LATIN1 2010 public.shape_setor_censitario | psql -d osm_cnefe_import 118 | ``` 119 | obs: above, the switch -s changes spatial reference from SIRGAS2000(SRID=4674) to WGS84 (SRID=4326) 120 | 121 | 122 | ###Importing OSM Brasil data: 123 | Commands to be run from linux terminal. Make sure you have osm2pgsql installed 124 | Inspiration: http://switch2osm.org/loading-osm-data/ 125 | 126 | 127 | 128 | Downloading the data: 129 | I use the [Brasil OSM file produced by Geofabrik](http://download.geofabrik.de/south-america/brazil.html) 130 | ``` 131 | wget http://download.geofabrik.de/south-america/brazil-latest.osm.pbf.md5 132 | wget http://download.geofabrik.de/south-america/brazil-latest.osm.pbf 133 | md5sum -c brazil-latest.osm.pbf.md5 134 | ``` 135 | Importing into PostgreSQL 136 | ``` 137 | osm2pgsql --create --slim -l \ 138 | --cache 4000 --hstore \ 139 | --style openstreetmap-carto.style --multi-geometry \ 140 | --host MYMACHINE--port 1234 --database MYDATABASE \ 141 | brazil-latest.osm.pbf 142 | ``` 143 | above replace the host, port and database info with the values for your setup. 144 | 145 | 146 | 147 | 148 | 149 | ### (optional) Importing OSM Brasil History File: 150 | 151 | 152 | Following this tutorial: https://github.com/MaZderMind/osm-history-renderer/blob/master/TUTORIAL.md 153 | 154 | Importing the data: 155 | ``` 156 | mkdir ~/osm_cnefe_import/OSM_Brasil/Brasil_history_file 157 | cd ~/osm_cnefe_import/OSM_Brasil/Brasil_history_file 158 | wget http://osm.personalwerk.de/full-history-extracts/latest/south-america/brazil.osh.pbf 159 | ``` 160 | 161 | Importing into postgres 162 | ``` 163 | ... 164 | ``` 165 | 166 | ##Data sources summary 167 | 168 | * CNEFE data: ftp://ftp.ibge.gov.br/Censos/Censo_Demografico_2010/Cadastro_Nacional_de_Enderecos_Fins_Estatisticos 169 | 170 | * Setor sensitario: ftp://geoftp.ibge.gov.br/malhas_digitais/censo_2010/setores_censitarios/ 171 | 172 | * [Brasil OSM file produced by Geofabrik](http://download.geofabrik.de/south-america/brazil.html): 173 | 174 | * http://download.geofabrik.de/south-america/brazil-latest.osm.pbf.md5 175 | * http://download.geofabrik.de/south-america/brazil-latest.osm.pbf 176 | * http://osm.personalwerk.de/full-history-extracts/latest/south-america/brazil.osh.pbf 177 | 178 | -------------------------------------------------------------------------------- /temp_older_code.txt: -------------------------------------------------------------------------------- 1 | ### CNEFE city blocks 2 | 3 | still waitting for CNEFE import code. In the end will generate tables 4 | 5 | CNEFE_blocks_Sao_Paulo 6 | CNEFE_block_street_relation_Sao_Paulo 7 | 8 | ### OSM city blocks 9 | 10 | To create city blocks from OSM we use the following algorithm, inspired by [this post](http://gis.stackexchange.com/questions/80498/how-to-transform-a-set-of-street-segments-into-city-blocks-with-postgis2): 11 | 12 | 0) Auxiliary functions 13 | 14 | ``` sql 15 | CREATE OR REPLACE FUNCTION retira_acentuacao(p_texto text) 16 | RETURNS text AS 17 | $BODY$ 18 | Select translate($1, 19 | 'áàâãäåaaaÁÂÃÄÅAAAÀéèêëeeeeeEEEÉEEÈìíîïìiiiÌÍÎÏÌIIIóôõöoooòÒÓÔÕÖOOOùúûüuuuuÙÚÛÜUUUUçÇñÑýÝ', 20 | 'aaaaaaaaaAAAAAAAAAeeeeeeeeeEEEEEEEiiiiiiiiIIIIIIIIooooooooOOOOOOOOuuuuuuuuUUUUUUUUcCnNyY' 21 | ); 22 | $BODY$ 23 | LANGUAGE sql VOLATILE 24 | COST 100; 25 | ``` 26 | 27 | 1) select only streets in OSM 28 | ``` sql 29 | CREATE TABLE OSM_streets AS 30 | SELECT * 31 | FROM planet_osm_line 32 | WHERE 33 | (highway='living_street' or highway='motorway' or highway='primary' or highway='proposed' or highway='raceway' or 34 | highway='residential' or highway='road' or highway='secondary' or highway='tertiary' or 35 | highway='track' or 36 | highway='trunk' or highway='unclassified' or route='road') 37 | CREATE INDEX OSM_streets_index ON OSM_streets USING gist (way); 38 | 39 | ``` 40 | Here selection the createria to select roads, or other line types that define bocks could be refined. An alternative could be 41 | ``` sql 42 | line.highway NOT IN ('construction', 'footway', 'path', 'steps', 'track', 'cycleway', 'pedestrian', 'abandoned', 43 | 'disused') AND 44 | (line.service NOT IN ('parking_aisle', 'driveway') OR line.service is null) AND (line.access NOT IN ('no', 'private') or line.access is null) AND 45 | ``` 46 | Let me know if you have a more precise way to identify streets. 47 | 48 | 2) match OSM_streets to the IBGE state and municipality layer 49 | ``` sql 50 | CREATE TABLE OSM_Streets_by_Mun AS 51 | SELECT cod_uf, cod_mun, OSM_Streets.* 52 | FROM OSM_Streets, UFs_Brasil, municipios_Brasil 53 | WHERE ST_Intersects(way,UFs_Brasil.geom) AND ST_Intersects(way,municipios_Brasil.geom) 54 | CREATE INDEX OSM_Streets_by_Mun_index ON OSM_Streets_by_Mun USING gist (way); 55 | ``` 56 | 57 | This is important to reduce the dimensionality of subsequent queries, constructing `blocks` only within municipality. OBS:Minor problem: This will lead to problems with blocks that cross municipall borders, which can occur in conurbated municipalities 58 | 59 | 60 | 3) Create OSM blocks for each municipality 61 | 62 | 3a) Union all street segments into a coommon multiline geom (ST_Union() ) in each municipality 63 | ``` sql 64 | CREATE TABLE OSM_streets_mergedlines AS 65 | SELECT cod_mun,ST_Union(way) as geom 66 | FROM OSM_streets_by_Mun 67 | GROUP BY cod_mun; 68 | CREATE INDEX OSM_streets_mergedlines_index ON OSM_streets_mergedlines USING gist (geom); 69 | ``` 70 | OBS: This generates a tale with 5538 municipalities. In the 2010 census municipal division there were 5564 municipalities. This 26 municipalities have no OSM data. 71 | 72 | 3b) extract all polygons formed from the unionioned streets using ST_Poligonize(). Theese are the city blocks. Notice it is necessary to Split multipoligon geom generated into a table with one poligon per line. 73 | 74 | ``` sql 75 | CREATE TABLE temp_OSM_blocks AS 76 | SELECT cod_mun, (blocks).path[1] AS path , (blocks).geom AS geom , ST_Buffer((blocks).geom,-0.0005) AS geom2 77 | FROM (SELECT cod_mun, ST_Dump(ST_Polygonize(geom)) AS blocks 78 | FROM OSM_streets_mergedlines 79 | GROUP BY cod_mun) AS foo; 80 | CREATE INDEX temp_OSM_blocks_index ON temp_OSM_blocks USING gist(geom); 81 | ``` 82 | 83 | 4) Bring the OSM city names to OSM Blocks 84 | 85 | Find the intersection of created polygons with the original street dataset to recover the names of the streets that carachterize each city block. 86 | 87 | ``` sql 88 | drop table OSM_block_street_relation 89 | CREATE TABLE OSM_block_street_relation AS 90 | SELECT OSM_streets_by_mun.*, 91 | temp_OSM_blocks.path,temp_OSM_blocks.geom, temp_OSM_blocks.geom2 92 | FROM temp_OSM_blocks, OSM_streets_by_mun 93 | WHERE temp_OSM_blocks.cod_mun = OSM_streets_by_mun.cod_mun AND 94 | ST_Intersects(temp_OSM_blocks.geom, OSM_streets_by_mun.way) AND 95 | GeometryType(ST_Multi(ST_Intersection(temp_OSM_blocks.geom, OSM_streets_by_mun.way)))='MULTILINESTRING'; 96 | CREATE INDEX OSM_block_street_relation_index ON OSM_block_street_relation USING gist(geom); 97 | ``` 98 | 99 | 5) Create OSM_Block with streetname array 100 | 101 | ``` sql 102 | REATE TABLE OSM_blocks AS 103 | SELECT cod_mun, path, geom, geom2, 104 | count(*) AS No_seg, 105 | count(name) AS No_names, 106 | count(distinct name) AS No_unique_names, 107 | array_agg(osm_id ORDER BY name) AS osm_id_array, 108 | array_agg(name ORDER BY name) AS osm_name_array, 109 | array_agg(upper(retira_acentuacao(name)) ORDER BY name) AS osm_name_semAcento_array 110 | FROM OSM_block_street_relation 111 | GROUP BY cod_mun, path, geom, geom2; 112 | CREATE INDEX OSM_blocks_index ON OSM_blocks USING gist(geom);; 113 | ``` 114 | 115 | 116 | ### OSM city blocks Sao Paulo 117 | 118 | I previously prototyped the code with Sao Paulo data 119 | 120 | 1) select only streets in OSM and a certain municipality (in this case Sao Paulo) 121 | 122 | ``` sql 123 | CREATE TABLE OSM_streets_Sao_Paulo AS 124 | select line.* 125 | from planet_osm_line as line, planet_osm_polygon as poly 126 | where (poly.admin_level='8' AND poly.name='São Paulo') AND 127 | (line.highway='living_street' or line.highway='motorway' or line.highway='primary' or line.highway='proposed' or line.highway='raceway' or 128 | line.highway='residential' or line.highway='road' or line.highway='secondary' or line.highway='tertiary' or 129 | line.highway='track' or 130 | line.highway='trunk' or line.highway='unclassified' or line.route='road') AND 131 | ST_Contains(poly.way,line.way) 132 | ``` 133 | 134 | 135 | 2) Union all street segments into a coommon multiline geom (ST_Union() ) 136 | 137 | ``` sql 138 | create table OSM_streets_Sao_Paulo_mergedlines as 139 | SELECT ST_Union(way) as geom FROM OSM_streets_Sao_Paulo; 140 | ``` 141 | 142 | 3) extract all polygons formed from the unionioned streets using ST_Poligonize(). Theese are the city blocks. Notice it is necessary to Split multipoligon geom generated into a table with one poligon per line. 143 | 144 | ``` sql 145 | CREATE TABLE OSM_blocks_Sao_Paulo AS 146 | select (blocks).path[1], (blocks).geom from 147 | (select ST_Dump(ST_Polygonize(geom)) as blocks from OSM_streets_Sao_Paulo_mergedlines) as foo; 148 | ``` 149 | 150 | 3b) (optional) For better visual rendering, substract (ST_Clip) the streets width from the city bock polygons. Preferably use street widths proportional to street type. 151 | 152 | ``` sql 153 | ALTER TABLE OSM_blocks_Sao_Paulo 154 | ADD geom_space2 geometry; 155 | UPDATE OSM_blocks_Sao_Paulo 156 | SET geom_space2=ST_Buffer(geom,-0.0005); 157 | ``` 158 | the is a little bug above (I`m not able to see the gaps in Qgis) 159 | To be uptated for a `buffer` proportional to street width. 160 | 161 | 162 | 4) Find the intersection of created polygons with the original street dataset to recover the names of the streets tha carachterize each city block. 163 | 164 | ``` sql 165 | create table OSM_block_street_relation_Sao_Paulo as 166 | select OSM_blocks_Sao_Paulo.path, OSM_streets_Sao_Paulo.* , 167 | ST_Intersects(OSM_blocks_Sao_Paulo.geom,OSM_streets_Sao_Paulo.way) 168 | from OSM_blocks_Sao_Paulo, OSM_streets_Sao_Paulo 169 | where ST_Intersects(OSM_blocks_Sao_Paulo.geom, OSM_streets_Sao_Paulo.way)=true and 170 | GeometryType(ST_Multi(ST_Intersection(OSM_blocks_Sao_Paulo.geom,OSM_streets_Sao_Paulo.way)))='MULTILINESTRING' 171 | ``` 172 | 173 | 174 | 175 | Now need to replicate 1-4 this for all of Brasil. 176 | 177 | 178 | TABLE time to run steps above (1 to 4) in Sao Paulo and all of Brazil 179 | 180 | query|Sao Paulo municipality|Sao Paulo min + spatial index |Brazil 181 | ---|---|---|--- 182 | N# of Street Segments|58k|58k|1751k 183 | OSM_Streets_by_Mun |n.a.|n.a.|15min 184 | ST_Union|8min|9min|167min 185 | ST_Dump(ST_Polygonize)|1min|1min|4min 186 | ST_Intersects()|10min|4min|59min 187 | array_agg|a|a|a 188 | 189 | All of OBS-Brazil is 30x larger than OSM-Sao Paulo 190 | 191 | 192 | ### Maching CNEFE and OSM city bocks 193 | matching within cities... (as a PL/pgSQL loop, otherwise query takes too long or does not run) 194 | 195 | The relevant tables are 196 | 197 | CNEFE_blocks_Sao_Paulo 198 | CNEFE_block_street_relation_Sao_Paulo 199 | 200 | OSM_blocks_Sao_Paulo 201 | OSM_block_street_relation_Sao_Paulo 202 | 203 | 204 | -------------------------------------------------------------------------------- /aux_files/test_queries_for_osm_setorCensitario_intersection.sql: -------------------------------------------------------------------------------- 1 | -- Flowing the suggestions at http://stackoverflow.com/questions/32907481/optimize-large-st-intersect-query-match-1-8m-osm-streets-to-317k-polygons 2 | -- I tryed different aprochages to matching the 1.8 million strets in OSM of Brazil to the 317k Enumeration districts. 3 | 4 | 5 | 6 | 7 | ---------------------- 8 | -- A, B, C . Creating spatial Indexes and CLUSTERING ON THEM. Not matching on muncipal codes 9 | -- A = criating buffer as subquery . B = pre-creating buffer in separate query . C = using ST_DWithin 10 | 11 | 12 | -- A) subquery to create buffer 13 | EXPLAIN 14 | CREATE TABLE OSM_Streets_by_SetorCensitarioA AS 15 | SELECT osm_id, cd_geocodi as cod_setor 16 | FROM OSM_Streets 17 | INNER JOIN 18 | (SELECT *, ST_Buffer(geom,0.0005) as geom_buffed 19 | FROM setor_censitarioL) AS foo 20 | ON ST_Intersects(way,geom_buffed) 21 | 22 | "Nested Loop (cost=0.00..284628404933.70 rows=185124060285 width=24)" 23 | " Join Filter: st_intersects(osm_streets.way, st_buffer(setor_censitariol.geom, 0.005::double precision))" 24 | " -> Seq Scan on osm_streets (cost=0.00..75902.88 rows=1753988 width=190)" 25 | " -> Materialize (cost=0.00..58671.51 rows=316634 width=2145)" 26 | " -> Seq Scan on setor_censitariol (cost=0.00..57088.34 rows=316634 width=2145)" 27 | 28 | 29 | --B) pre compiling the buffer and running the main query 30 | drop table setor_censitarioL2 31 | CREATE TABLE setor_censitarioL2 AS 32 | SELECT *, substring(cd_geocodi,1,7) AS cod_mun , 33 | ST_Buffer(geom,0.0005) as geom_buffed 34 | FROM setor_censitarioL; 35 | CREATE INDEX setor_censitarioL2_index2 ON setor_censitarioL2 USING gist (cod_mun); 36 | 37 | 38 | EXPLAIN 39 | CREATE TABLE OSM_Streets_by_SetorCensitarioB AS 40 | SELECT osm_id, cd_geocodi as cod_setor 41 | FROM OSM_Streets 42 | INNER JOIN setor_censitarioL2 43 | ON ST_Intersects(way,geom_buffed); 44 | 45 | "Nested Loop (cost=0.41..15401715.81 rows=597184609 width=24)" 46 | " -> Seq Scan on setor_censitariol2 (cost=0.00..119821.74 rows=316574 width=1921)" 47 | " -> Index Scan using osm_streets_index on osm_streets (cost=0.41..47.69 rows=58 width=190)" 48 | " Index Cond: (way && setor_censitariol2.geom_buffed)" 49 | " Filter: _st_intersects(way, setor_censitariol2.geom_buffed)" 50 | 51 | 52 | --C) Matching with ST_DWithin 53 | EXPLAIN 54 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 55 | SELECT osm_id, cd_geocodi as cod_setor 56 | FROM OSM_Streets 57 | INNER JOIN setor_censitarioL 58 | ON ST_DWithin(way,geom,0.0005); 59 | 60 | "Nested Loop (cost=0.41..15439215.66 rows=185124 width=24)" 61 | " -> Seq Scan on setor_censitariol (cost=0.00..57088.34 rows=316634 width=2145)" 62 | " -> Index Scan using osm_streets_index on osm_streets (cost=0.41..48.57 rows=1 width=190)" 63 | " Index Cond: (way && st_expand(setor_censitariol.geom, 0.005::double precision))" 64 | " Filter: ((setor_censitariol.geom && st_expand(way, 0.005::double precision)) AND _st_dwithin(way, setor_censitariol.geom, 0.005::double precision))" 65 | 66 | 67 | 68 | ------------------------- 69 | -- D, E. The difference now is that I add indexes on cod_mun for both tables and use the cod_mun as a matching criteria. 70 | -- Note that the CLUSTER is still only on the index of the spatial index 71 | -- D = pre-creating buffer in separate query . E = using ST_DWithin 72 | 73 | 74 | -- i.e. I created the index for cod_mun on both tables 75 | CREATE INDEX setor_censitarioL2_index ON setor_censitarioL2 USING gist (geom); 76 | CREATE INDEX setor_censitarioL2_index2 ON setor_censitarioL2 USING gist (cod_mun); 77 | CLUSTER setor_censitarioL2 using setor_censitarioL2_index2; -- 75s 78 | 79 | 80 | CREATE INDEX OSM_Streets_by_Mun_index ON OSM_Streets_by_Mun USING gist (way); 81 | CREATE INDEX OSM_Streets_by_Mun_index2 ON OSM_Streets_by_Mun USING gist (cod_mun); 82 | CLUSTER OSM_Streets_by_Mun using OSM_Streets_by_Mun_index; 83 | 84 | 85 | --D) 86 | 87 | EXPLAIN 88 | CREATE TABLE OSM_Streets_by_SetorCensitarioD AS 89 | SELECT osm_id, cd_geocodi as cod_setor 90 | FROM OSM_Streets_by_mun 91 | INNER JOIN setor_censitarioL2 92 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 93 | ST_Intersects(way,geom_buffed); 94 | 95 | 96 | "Nested Loop (cost=0.41..531970.67 rows=2854485 width=24)" 97 | " -> Seq Scan on setor_censitariol2 (cost=0.00..)" 98 | " -> Index Scan using osm_streets_by_mun_index3 on osm_streets_by_mun (cost=0.41..1.29 rows=1 width=268)" 99 | " Index Cond: (((cod_mun)::text = setor_censitariol2.cod_mun) AND (way && setor_censitariol2.geom_buffed))" 100 | " Filter: _st_intersects(way, setor_censitariol2.geom_buffed)" 101 | 102 | 103 | 104 | --E) Matching with municipal code and ST_DWithin 105 | 106 | EXPLAIN 107 | CREATE TABLE OSM_Streets_by_SetorCensitarioE AS 108 | SELECT osm_id, cd_geocodi as cod_setor 109 | FROM OSM_Streets_by_mun 110 | INNER JOIN setor_censitarioL2 111 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 112 | ST_DWithin(way,geom,0.0005); 113 | 114 | "Nested Loop (cost=0.41..534344.97 rows=744 width=24)" 115 | " -> Seq Scan on setor_censitariol2 (cost=0.00..119821.74 rows=316574 width=2156)" 116 | " -> Index Scan using osm_streets_by_mun_index3 on osm_streets_by_mun (cost=0.41..1.30 rows=1 width=268)" 117 | " Index Cond: (((cod_mun)::text = setor_censitariol2.cod_mun) AND (way && st_expand(setor_censitariol2.geom, 0.005::double precision)))" 118 | " Filter: ((setor_censitariol2.geom && st_expand(way, 0.005::double precision)) AND _st_dwithin(way, setor_censitariol2.geom, 0.005::double precision))" 119 | 120 | 121 | 122 | ------------------------- 123 | -- F, G Now I create index base on both cod_mun and spatial variable. And cluster both datases on that index 124 | -- F = pre-creating buffer in separate query . G = using ST_DWithin 125 | 126 | CREATE INDEX setor_censitarioL2_index3 ON setor_censitarioL2 USING gist (cod_mun,geom); --46s 127 | CLUSTER setor_censitarioL2 using setor_censitarioL2_index3; -- 131s 128 | 129 | CREATE INDEX OSM_Streets_by_Mun_index3 ON OSM_Streets_by_Mun USING gist (cod_mun,way); 130 | CLUSTER OSM_Streets_by_Mun using OSM_Streets_by_Mun_index3; -- 743 131 | 132 | 133 | 134 | --F) 135 | 136 | EXPLAIN 137 | CREATE TABLE OSM_Streets_by_SetorCensitarioA AS 138 | SELECT osm_id, cd_geocodi as cod_setor 139 | FROM OSM_Streets_by_mun 140 | INNER JOIN setor_censitarioL2 141 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 142 | ST_Intersects(way,geom_buffed); 143 | 144 | 145 | "Nested Loop (cost=0.41..528928.67 rows=2854485 width=24)" 146 | " -> Seq Scan on setor_censitariol2 (cost=0.00..119875.74 rows=316574 width=1929)" 147 | " -> Index Scan using osm_streets_by_mun_index3 on osm_streets_by_mun (cost=0.41..1.28 rows=1 width=268)" 148 | " Index Cond: (((cod_mun)::text = setor_censitariol2.cod_mun) AND (way && setor_censitariol2.geom_buffed))" 149 | " Filter: _st_intersects(way, setor_censitariol2.geom_buffed)" 150 | 151 | 152 | 153 | --G) Matching with municipal code and ST_DWithin 154 | 155 | EXPLAIN 156 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 157 | SELECT osm_id, cd_geocodi as cod_setor 158 | FROM OSM_Streets_by_mun 159 | INNER JOIN setor_censitarioL2 160 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 161 | ST_DWithin(way,geom,0.0005); 162 | 163 | "Nested Loop (cost=0.41..531302.97 rows=744 width=24)" 164 | " -> Seq Scan on setor_censitariol2 (cost=0.00..119875.74 rows=316574 width=2156)" 165 | " -> Index Scan using osm_streets_by_mun_index3 on osm_streets_by_mun (cost=0.41..1.29 rows=1 width=268)" 166 | " Index Cond: (((cod_mun)::text = setor_censitariol2.cod_mun) AND (way && st_expand(setor_censitariol2.geom, 0.005::double precision)))" 167 | " Filter: ((setor_censitariol2.geom && st_expand(way, 0.005::double precision)) AND _st_dwithin(way, setor_censitariol2.geom, 0.005::double precision))" 168 | 169 | -- H) Adding && clause 170 | 171 | EXPLAIN 172 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 173 | SELECT osm_id, cd_geocodi as cod_setor 174 | FROM OSM_Streets_by_mun 175 | INNER JOIN setor_censitarioL2 176 | ON OSM_Streets_by_mun.cod_mun=setor_censitarioL2.cod_mun AND 177 | way && geom 178 | ST_DWithin(way,geom,0.0005); 179 | 180 | "Nested Loop (cost=0.67..538425.89 rows=8560395 width=24)" 181 | " -> Seq Scan on setor_censitariol2 (cost=0.00..119875.74 rows=316574 width=2156)" 182 | " -> Nested Loop (cost=0.67..1.31 rows=1 width=268)" 183 | " -> Index Scan using osm_streets_by_mun_index3 on osm_streets_by_mun (cost=0.41..1.03 rows=1 width=268)" 184 | " Index Cond: (((cod_mun)::text = setor_censitariol2.cod_mun) AND (way && setor_censitariol2.geom))" 185 | " -> Function Scan on st_dwithin (cost=0.26..0.27 rows=1 width=0)" 186 | 187 | 188 | -- Comparing Results of the Explains 189 | 190 | Nested Loop 191 | B 15401715.81 rows=597184609 width=24 192 | C 15439215.66 rows= 185124 width=24 193 | D 531970.67 rows= 2854485 width=24 194 | E 534344.97 rows= 744 width=24 195 | F 528928.67 rows= 2854485 width=24 196 | G 531302.97 rows= 744 width=24 197 | H 538425.89 rows= 8560395 width=24 198 | 199 | 200 | Seq Scan 201 | B 119821.74 rows= 316574 width=1921 202 | C 57088.34 rows= 316634 width=2145 203 | D 0.00.. 204 | E 119821.74 rows= 316574 width=2156 205 | F 19875.74 rows= 316574 width=1929 206 | G 119875.74 rows= 316574 width=2156 207 | H 119875.74 rows= 316574 width=2156 208 | 209 | Index Scan 210 | B 47.69 rows= 58 width=190 211 | C 48.57 rows= 1 width=190 212 | D 1.29 rows= 1 width=268 213 | E 1.30 rows= 1 width=268 214 | F 1.28 rows= 1 width=268 215 | G 1.29 rows= 1 width=268 216 | H 1.03 rows= 1 width=268 217 | -- conclusion. it seems that the Nested Loop is the most expensive part of the queries, and query G should be the most efficient 218 | 219 | G 5757s= 96min = 1h36 , buffer 0.005 Query returned successfully: 22366081 rows affected, 5757770 ms execution time. 220 | -------------------------------------------------------------------------------- /OMS_and_CNEFE_blocks_matching.sql: -------------------------------------------------------------------------------- 1 | -- This file documents how to match OSM and CNEFE data. 2 | -- This involves: 3 | -- (a) creating OSM "city blocks", which are formed defined as polygons formed by existing OSM streets. For each block I define a field with an array containing the names of its neighboring streets. 4 | -- (b) modifying the CNEFE structure so that blocks table also contains an array with the names of neighboring streets 5 | -- (c) matching OSM "city blocks" (a) to CNEFE city blocks (b) on the streets names array. 6 | -- Bellow I describe each step in more detail 7 | 8 | 9 | -------------------------------- 10 | -- AUXILIARY FUNCTIONS: 11 | 12 | CREATE OR REPLACE FUNCTION retira_acentuacao(p_texto text) 13 | RETURNS text AS 14 | $BODY$ 15 | Select translate($1, 16 | 'áàâãäåaaaÁÂÃÄÅAAAÀéèêëeeeeeEEEÉEEÈìíîïìiiiÌÍÎÏÌIIIóôõöoooòÒÓÔÕÖOOOùúûüuuuuÙÚÛÜUUUUçÇñÑýÝ', 17 | 'aaaaaaaaaAAAAAAAAAeeeeeeeeeEEEEEEEiiiiiiiiIIIIIIIIooooooooOOOOOOOOuuuuuuuuUUUUUUUUcCnNyY' 18 | ); 19 | $BODY$ 20 | LANGUAGE sql VOLATILE 21 | COST 100; 22 | 23 | 24 | -------------------------------- 25 | -- A) creting OSM "city blocks": 26 | 27 | --1) select only streets in OSM 28 | CREATE TABLE OSM_streets AS 29 | SELECT * 30 | FROM planet_osm_line 31 | WHERE 32 | (highway='living_street' or highway='motorway' or highway='primary' or highway='proposed' or highway='raceway' or 33 | highway='residential' or highway='road' or highway='secondary' or highway='tertiary' or 34 | highway='track' or 35 | highway='trunk' or highway='unclassified' or route='road'); 36 | CREATE INDEX OSM_streets_index ON OSM_streets USING gist (way); 37 | CLUSTER OSM_Streets using OSM_Streets_index; 38 | 39 | /* Here selection the createria to select roads, or other line types that define bocks could be refined. An alternative could be 40 | line.highway NOT IN ('construction', 'footway', 'path', 'steps', 'track', 'cycleway', 'pedestrian', 'abandoned', 41 | 'disused') AND 42 | (line.service NOT IN ('parking_aisle', 'driveway') OR line.service is null) AND (line.access NOT IN ('no', 'private') or line.access is null) AND 43 | Let me know if you have a more precise way to identify streets. 44 | */ 45 | 46 | 47 | --2) match OSM_streets to the IBGE state and municipality and Enumeration districs (setor censitario) layers 48 | 49 | --2a) municipality match 50 | CREATE TABLE OSM_Streets_by_Mun AS 51 | SELECT cod_uf, cod_mun, OSM_Streets.* 52 | FROM OSM_Streets, UFs_Brasil, municipios_Brasil 53 | WHERE ST_Intersects(way,UFs_Brasil.geom) AND ST_Intersects(way,municipios_Brasil.geom); 54 | 55 | CREATE INDEX OSM_Streets_by_Mun_index ON OSM_Streets_by_Mun USING gist (way); 56 | CREATE INDEX OSM_Streets_by_Mun_index2 ON OSM_Streets_by_Mun USING gist (cod_mun); 57 | CREATE INDEX OSM_Streets_by_Mun_index3 ON OSM_Streets_by_Mun USING gist (cod_mun,way); 58 | CLUSTER OSM_Streets_by_Mun using OSM_Streets_by_Mun_index; 59 | 60 | --This is important to reduce the dimensionality of subsequent queries, constructing blocks only within municipality. OBS:Minor problem: This will lead to problems with blocks that cross municipall borders, which can occur in conurbated municipalities 61 | 62 | 63 | --2b) ED match 64 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 65 | SELECT osm_id, cd_geocodi as cod_setor 66 | FROM OSM_Streets 67 | INNER JOIN 68 | (SELECT *, ST_Buffer(geom,0.005) as geom_buffed 69 | FROM setor_censitarioL) AS foo 70 | ON ST_Intersects(way,geom_buffed) 71 | 72 | 73 | 74 | ---- Find place for this.... 75 | -- 4b) Enumeration district level 76 | 77 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 78 | SELECT OSM_Streets_by_Mun.*, setor_censitarioL.geom 79 | FROM OSM_Streets_by_Mun, setor_censitarioL 80 | WHERE OSM_Streets_by_Mun.cod_UF= substring(setor_censitarioL.cd_geocodi,1,2) AND 81 | OSM_Streets_by_Mun.cod_mun= substring(setor_censitarioL.cd_geocodi,1,7) AND 82 | ST_Intersects(way,ST_Buffer(setor_censitarioL.geom,0.005))=true 83 | 84 | -- the above query never finishes, eventually chashin the server. 85 | -- I asked a question about it here http://stackoverflow.com/questions/32907481/optimize-large-st-intersect-query-match-1-8m-osm-streets-to-317k-polygons 86 | 87 | -- Since it does not run with the 1.8 million streets I tryed with the 480k fully named blocks I created in (OSM_blocks_fullyNamed). 88 | -- Also, following previous sucgestoins I pre-compute a new geom with the buffer. 89 | 90 | 91 | CREATE TABLE setor_censitarioL2 AS 92 | SELECT *, ST_Buffer(geom,0.005) as geom_buffed 93 | FROM setor_censitarioL 94 | 95 | 96 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 97 | SELECT OSM_Streets_by_Mun.*, setor_censitarioL.geom 98 | FROM OSM_Streets_by_Mun, setor_censitarioL 99 | WHERE OSM_Streets_by_Mun.cod_UF= substring(setor_censitarioL.cd_geocodi,1,2) AND 100 | OSM_Streets_by_Mun.cod_mun= substring(setor_censitarioL.cd_geocodi,1,7) AND 101 | ST_Intersects(way,ST_Buffer(setor_censitarioL.geom,0.005))=true 102 | 103 | 104 | -------- 105 | 106 | 107 | --3) Create OSM blocks for each municipality 108 | 109 | --3a) Union all street segments into a coommon multiline geom (ST_Union() ) in each municipality 110 | 111 | CREATE TABLE OSM_streets_mergedlines AS 112 | SELECT cod_mun,ST_Union(way) as geom 113 | FROM OSM_streets_by_Mun 114 | GROUP BY cod_mun; 115 | CREATE INDEX OSM_streets_mergedlines_index ON OSM_streets_mergedlines USING gist (geom); 116 | 117 | --OBS: This generates a tale with 5538 municipalities. In the 2010 census municipal division there were 5564 municipalities. This 26 municipalities have no OSM data. 118 | 119 | --3b) extract all polygons formed from the unionioned streets using ST_Poligonize(). Theese are the city blocks. Notice it is necessary to Split multipoligon geom generated into a table with one poligon per line. 120 | 121 | CREATE TABLE temp_OSM_blocks AS 122 | SELECT cod_mun, (blocks).path[1] AS path , (blocks).geom AS geom , ST_Buffer((blocks).geom,-0.0005) AS geom2 123 | FROM (SELECT cod_mun, ST_Dump(ST_Polygonize(geom)) AS blocks 124 | FROM OSM_streets_mergedlines 125 | GROUP BY cod_mun) AS foo; 126 | CREATE INDEX temp_OSM_blocks_index ON temp_OSM_blocks USING gist(geom); 127 | 128 | --4) Bring the OSM municipality and ED codes to to OSM Blocks 129 | --Find the intersection of created polygons with the original street dataset to recover the names of the streets that carachterize each city block. 130 | 131 | CREATE TABLE OSM_block_street_relation AS 132 | SELECT OSM_streets_by_mun.*, 133 | temp_OSM_blocks.path,temp_OSM_blocks.geom, temp_OSM_blocks.geom2 134 | FROM temp_OSM_blocks, OSM_streets_by_mun 135 | WHERE temp_OSM_blocks.cod_mun = OSM_streets_by_mun.cod_mun AND 136 | ST_Intersects(temp_OSM_blocks.geom, OSM_streets_by_mun.way) AND 137 | GeometryType(ST_Multi(ST_Intersection(temp_OSM_blocks.geom, OSM_streets_by_mun.way)))='MULTILINESTRING'; 138 | UPDATE OSM_block_street_relation SET name=trim(name); 139 | CREATE INDEX OSM_block_street_relation_index ON OSM_block_street_relation USING gist(geom); 140 | 141 | 142 | 143 | 144 | 145 | --5) Create OSM_Block with street name array 146 | 147 | CREATE TABLE OSM_blocks AS 148 | SELECT cod_mun, path, geom AS geom_osm_block, geom2 AS geom2_osm_block, 149 | count(*) AS No_seg, 150 | count(name) AS No_names, 151 | count(distinct name) AS No_unique_names, 152 | array_agg(osm_id ORDER BY upper(retira_acentuacao(name))) AS osm_id_array, 153 | array_agg(name ORDER BY upper(retira_acentuacao(name))) AS osm_name_array, 154 | array_agg(upper(retira_acentuacao(name)) ORDER BY upper(retira_acentuacao(name))) AS osm_name_semAcento_array 155 | FROM OSM_block_street_relation 156 | GROUP BY cod_mun, path, geom_osm_block, geom2_osm_block; 157 | CREATE INDEX OSM_blocks_index ON OSM_blocks USING gist(geom_osm_block); 158 | 159 | 160 | --6) Select only OSM-Blocks that ahve all streets named 161 | 162 | CREATE TABLE OSM_blocks_fullyNamed AS 163 | SELECT * 164 | from OSM_blocks 165 | where No_seg=No_names AND No_seg=No_unique_names 166 | 167 | -- OBS THis lowers the number of blocks substantially, from 1,6m blocks to 480k fully named blocks. This hapens in 97% (= 2090838/2145264) 168 | 169 | 170 | 171 | -------------------------------- 172 | -- B) preparing CNEFE blocks "city blocks": 173 | 174 | --1) Creating table with blocks and street names. 175 | -- OBS The WHERE clause selects only CNEFE blocks with only one street name per block face. This hapens in 97% (= 2090838/2145264) of CNEFE blocks. Only 37% (= 791539/2145264) of CNEFE blocks have 4 faces (and only 1 street name per face) 176 | 177 | 178 | CREATE TABLE cnefe2010.aux_quadra AS 179 | SELECT setor.idn_setor, setor.cod_setor, situacao_setor.idn_situacao_setor, situacao_setor.dsc_situacao_setor, 180 | quadra.idn_quadra, quadra.num_quadra, 181 | face.idn_face, face_tem_logradouros.idn_logradouro, 182 | tipo_logradouro.dsc_tipo_logradouro, logradouro.dsc_titulo_logradouro, logradouro.nme_logradouro, 183 | trim(concat_ws(' ',tipo_logradouro.dsc_tipo_logradouro,logradouro.dsc_titulo_logradouro,logradouro.nme_logradouro)) AS nomeC_logradouro 184 | FROM cnefe2010.setor 185 | LEFT JOIN cnefe2010.situacao_setor 186 | ON cnefe2010.setor.idn_situacao_setor = cnefe2010.situacao_setor.idn_situacao_setor 187 | LEFT JOIN cnefe2010.quadra 188 | ON cnefe2010.setor.idn_setor = cnefe2010.quadra.idn_setor 189 | LEFT JOIN cnefe2010.face 190 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 191 | 192 | LEFT JOIN cnefe2010.face_tem_logradouros 193 | ON cnefe2010.face.idn_face = cnefe2010.face_tem_logradouros.idn_face 194 | LEFT JOIN cnefe2010.logradouro 195 | ON cnefe2010.face_tem_logradouros.idn_logradouro=cnefe2010.logradouro.idn_logradouro 196 | LEFT JOIN cnefe2010.tipo_logradouro 197 | ON cnefe2010.logradouro.idn_tipo_logradouro = cnefe2010.tipo_logradouro.idn_tipo_logradouro 198 | WHERE (quadra.idn_quadra) 199 | IN ( SELECT a.idn_quadra 200 | FROM ( SELECT quadra.idn_quadra, face.idn_face , count(face_tem_logradouros.idn_logradouro) as N 201 | FROM cnefe2010.quadra 202 | LEFT JOIN cnefe2010.face 203 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 204 | LEFT JOIN cnefe2010.face_tem_logradouros 205 | ON cnefe2010.face.idn_face = cnefe2010.face_tem_logradouros.idn_face 206 | GROUP BY quadra.idn_quadra, face.idn_face ) AS a 207 | GROUP BY a.idn_quadra 208 | HAVING avg(a.N)=1) 209 | 210 | --2) Collapsing the data to a CNEFE block with street name array 211 | 212 | CREATE TABLE cnefe2010.quadra_array_ruas AS 213 | SELECT substring(cod_setor,1,7) AS cod_mun, idn_setor, cod_setor, idn_situacao_setor, dsc_situacao_setor, 214 | idn_quadra, num_quadra, count(*) as no_faces, 215 | array_agg(idn_face ORDER BY nomeC_logradouro) as array_idn_face, array_agg(nomeC_logradouro ORDER BY nomeC_logradouro) as array_nomeC_logradouro 216 | FROM cnefe2010.aux_quadra 217 | GROUP BY cod_mun, idn_setor, cod_setor, idn_situacao_setor, dsc_situacao_setor, idn_quadra, num_quadra 218 | 219 | 220 | 221 | 222 | -------------------------------- 223 | -- C) Matching OSM-Blocks (A) with CNEFE-Blocks (B) based on municipality and street names of each block. 224 | 225 | CREATE TABLE OSM_CNEFE_block_matches AS 226 | SELECT OSM_blocks_fullyNamed.cod_mun, 227 | idn_setor, cod_setor, idn_situacao_setor, dsc_situacao_setor, 228 | idn_quadra, 229 | no_faces, 230 | path, No_seg, No_names, No_unique_names, osm_id_array, osm_name_array, 231 | geom_osm_block, geom2_osm_block 232 | FROM cnefe2010.quadra_array_ruas, OSM_blocks_fullyNamed 233 | where OSM_blocks_fullyNamed.cod_mun = quadra_array_ruas.cod_mun; 234 | AND osm_name_semAcento_array = array_nomeC_logradouro; 235 | 236 | 237 | CREATE INDEX OSM_blocks_index ON OSM_blocks USING gist(geom_osm_block); 238 | 239 | 240 | --we find 95160 block matches, located in 1822 municipios. 241 | 242 | -- OBS Next step should be try a fuzzy match on the street name arrays 243 | 244 | 245 | 246 | 247 | 248 | ------------------------- 249 | ------------------------- 250 | ------------------------- 251 | other auxiliary queries, tests, to do list (and maybe some garbage) 252 | #aux_setor 253 | 254 | 255 | --matched blocks that are also the full ED 256 | SELECT count(*) 257 | FROM OSM_CNEFE_block_matches 258 | WHERE idn_setor in 259 | (SELECT idn_setor 260 | FROM cnefe2010.quadra 261 | GROUP BY idn_setor 262 | HAVING count(*) = 1) 263 | 264 | SELECT cod_mun, count(*) 265 | FROM OSM_CNEFE_block_matches 266 | WHERE idn_setor in 267 | (SELECT idn_setor 268 | FROM cnefe2010.quadra 269 | GROUP BY idn_setor 270 | HAVING count(*) = 1) 271 | GROUP BY cod_mun 272 | ORDER BY count(*) desc 273 | 274 | --312 mil setores. 275 | -- Destes 93 mil setores tem um so quarteirao 276 | -- Dentre estes de um so quarteirao 952 foram pareados com o OSM 277 | -- Eses pareados pertencem a 81 municipios 278 | 279 | SELECT idn_setor, 280 | count(idn_quadra), 281 | count(osm_id_array) 282 | FROM cnefe2010.quadra 283 | LEFT JOIN OSM_CNEFE_block_matches 284 | ON quadra.idn_quadra = OSM_CNEFE_block_matches.idn_quadra 285 | GROUP BY idn_setor 286 | 287 | 288 | -- setores com todas as quadras mapeadas 289 | SELECT cod_mun, count(*) 290 | FROM 291 | (SELECT cod_mun, foo.idn_setor, 292 | N_matched_blocks, N_blocks 293 | FROM 294 | (SELECT cod_mun, idn_setor, 295 | count(osm_id_array) AS N_matched_blocks 296 | FROM OSM_CNEFE_block_matches 297 | GROUP BY cod_mun, idn_setor ) AS foo 298 | INNER JOIN 299 | (SELECT idn_setor, count(quadra.idn_quadra) AS N_blocks 300 | FROM cnefe2010.quadra 301 | GROUP BY idn_setor 302 | ) AS baa 303 | ON foo.idn_setor = baa.idn_setor 304 | WHERE N_matched_blocks = N_blocks) as bbb 305 | GROUP BY cod_mun 306 | ORDER BY count(*) desc 307 | 308 | -- 2272 setores tem todas as quadras mapeadas (isso e numero de linhas da subquery bbb, acima). 309 | -- que por sua vez pertencem a 207 municipios. 310 | 311 | 312 | 313 | -- creating table with EDs that could be matched in the ED shapefile and the agregation of OSM-Blocks. For each we ED e calculate de distance and angle between the ED shapefile and OSM 314 | 315 | CREATE TABLE control_points_SC2OSM AS 316 | SELECT cod_mun, idn_setor, cod_setor, 317 | setor_censitarioL.geom as geom_SC, 318 | ST_Centroid(setor_censitarioL.geom) AS point_SC, 319 | ST_Union(geom_osm_block) AS geom_osm_setor, 320 | ST_Centroid(ST_Union(geom_osm_block)) AS point_osm_setor, 321 | ST_Distance( ST_Centroid(setor_censitarioL.geom), 322 | ST_Centroid(ST_Union(geom_osm_block)) ) AS distance_SC2OSM, 323 | ST_Azimuth( ST_Centroid(setor_censitarioL.geom), 324 | ST_Centroid(ST_Union(geom_osm_block)) ) AS angle_SC2OSM, 325 | ST_Distance( ST_Centroid(ST_Transform(setor_censitarioL.geom,utmzone(ST_Centroid(setor_censitarioL.geom)))), 326 | ST_Centroid(ST_Transform(ST_Union(geom_osm_block),utmzone(ST_Centroid(ST_Union(geom_osm_block))))) ) AS dist_M_SC2OSM 327 | FROM OSM_CNEFE_block_matches 328 | INNER JOIN setor_censitarioL 329 | ON OSM_CNEFE_block_matches.cod_setor = setor_censitarioL.cd_geocodi 330 | GROUP BY cod_mun, idn_setor, cod_setor, geom_SC 331 | HAVING idn_setor IN 332 | ( SELECT foo.idn_setor 333 | FROM 334 | (SELECT cod_mun, idn_setor, 335 | count(osm_id_array) AS N_matched_blocks 336 | FROM OSM_CNEFE_block_matches 337 | GROUP BY cod_mun, idn_setor ) AS foo 338 | INNER JOIN 339 | (SELECT idn_setor, count(quadra.idn_quadra) AS N_blocks 340 | FROM cnefe2010.quadra 341 | GROUP BY idn_setor 342 | ) AS baa 343 | ON foo.idn_setor = baa.idn_setor 344 | WHERE N_matched_blocks = N_blocks 345 | ) 346 | 347 | -- Visual inspection of theese cases shows that is works great. However some sectors are quite different thatn they should be. I need to add a layer of comparing areas or perimeters and cutting wheen these are too diff 348 | 349 | 350 | 351 | 352 | 353 | 354 | 355 | 356 | #Testes para diferentes filtros. 357 | SELECT a.idn_quadra , avg(a.N) 358 | FROM ( SELECT quadra.idn_quadra, face.idn_face , count(face_tem_logradouros.idn_logradouro) as N 359 | FROM cnefe2010.quadra 360 | LEFT JOIN cnefe2010.face 361 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 362 | LEFT JOIN cnefe2010.face_tem_logradouros 363 | ON cnefe2010.face.idn_face = cnefe2010.face_tem_logradouros.idn_face 364 | GROUP BY quadra.idn_quadra, face.idn_face ) AS a 365 | GROUP BY a.idn_quadra 366 | HAVING avg(a.N)=1 AND count(*)=4 367 | 2145264 rows retrieved. 368 | 2090838 rows , 97% das quadras tem todas as faces com apenas uma rua. 369 | 2090838 rows , 97% das quadras tem todas as faces com apenas uma rua. 370 | 791539 rows, 37% das quadras tem 4 faces e todas as faces com apenas uma rua. 371 | This hapens in 97% (= 2090838/2145264) of CNEFE blocks 372 | Only 37% (= 791539/2145264) of CNEFE blocks have 4 faces (and only 1 street name per face) 373 | 374 | 375 | 376 | 377 | CREATE TABLE OSM_Streets_by_SetorCensitario AS 378 | SELECT cod_uf, cod_mun, cd_geocodi as cod_setor, OSM_Streets.* 379 | FROM OSM_Streets, UFs_Brasil, municipios_Brasil, setor_censitarioL 380 | WHERE ST_Intersects(way,UFs_Brasil.geom) 381 | AND ST_Intersects(way,municipios_Brasil.geom) 382 | AND ST_Intersects(way,ST_Buffer(setor_censitarioL.geom,0.005))=true 383 | 384 | 385 | 386 | 387 | 388 | 389 | 390 | 391 | 392 | 393 | 394 | 395 | 396 | ---------------------------------------- 397 | 398 | --statistics on matched blocks 399 | SELECT count(*) 400 | FROM ( 401 | SELECT setor.idn_setor, setor.cod_setor, situacao_setor.idn_situacao_setor, situacao_setor.dsc_situacao_setor, 402 | quadra.idn_quadra, quadra.num_quadra, 403 | face.idn_face, 404 | endereco.idn_endereco, 405 | domicilio.idn_domicilio 406 | 407 | FROM cnefe2010.setor 408 | LEFT JOIN cnefe2010.situacao_setor 409 | ON cnefe2010.setor.idn_situacao_setor = cnefe2010.situacao_setor.idn_situacao_setor 410 | LEFT JOIN cnefe2010.quadra 411 | ON cnefe2010.setor.idn_setor = cnefe2010.quadra.idn_setor 412 | LEFT JOIN cnefe2010.face 413 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 414 | LEFT JOIN cnefe2010.endereco 415 | ON cnefe2010.face.idn_face = cnefe2010.endereco.idn_face 416 | LEFT JOIN cnefe2010.domicilio 417 | ON cnefe2010.endereco.idn_endereco = cnefe2010.domicilio.idn_endereco 418 | WHERE (setor.idn_setor, quadra.idn_quadra) in (SELECT idn_setor, idn_quadra FROM OSM_CNEFE_block_matches) 419 | ) AS foo 420 | 421 | --faces de quarteiroes mapeadas - 370mil (370213) 422 | --enderecos mapeados - 1 milhao (1039728) (de um total de 47 milhoes) 423 | --domicilios mapeados - 1.7 milhao (1709243) de domicilios (de um total de 10 milhoes) 424 | 425 | -- block matches by municipality 426 | 427 | select cod_mun, count(*) 428 | from OSM_CNEFE_block_matches 429 | group by cod_mun 430 | order by count(*) desc 431 | 432 | select count(*) 433 | from OSM_streets_by_mun 434 | where cod_mun= '3550308' 435 | group by cod_mun 436 | 437 | 438 | 439 | /*ideias e to dos 440 | 0) Rever importacao dos dados da tabela de Enderecos e domicilios, ambas tem apenas 11 milhoes, quando deveri ser mais para 81 milhoes. 441 | 1) relacao entre as tabelas - sao todas aninhadas? Rever o tipo de Join correto para usar 442 | 2) verificar se os CEPs sao aninhados nas faces de quarteirao 443 | 3) atualizar github 444 | 4) testar quatos dos quarteiroes achados sao de setores de um so quarteirao 445 | 5) rodar a query OSM vs. setor censitario. (esta muito lento) 446 | 6) pareamentos probabilisticos 447 | */ 448 | 449 | 450 | --criando a tabela com No de CEPs por face de quadra 451 | CREATE TABLE cnefe2010.ceps_by_face AS 452 | SELECT idn_setor, cod_setor, idn_situacao_setor, dsc_situacao_setor, 453 | idn_quadra, num_quadra, 454 | idn_face, 455 | cep_null, 456 | count(*) AS No_ceps_por_face, 457 | array_agg(No_end_face_cep ORDER BY num_cep) AS array_No_end_face_cep, 458 | array_agg(num_cep ORDER BY num_cep) AS array_ceps 459 | FROM ( 460 | SELECT setor.idn_setor, setor.cod_setor, situacao_setor.idn_situacao_setor, situacao_setor.dsc_situacao_setor, 461 | quadra.idn_quadra, quadra.num_quadra, 462 | face.idn_face, 463 | num_cep, 464 | num_cep IS NULL AS cep_null, 465 | count(*) AS No_end_face_cep 466 | FROM cnefe2010.setor 467 | LEFT JOIN cnefe2010.situacao_setor 468 | ON cnefe2010.setor.idn_situacao_setor = cnefe2010.situacao_setor.idn_situacao_setor 469 | LEFT JOIN cnefe2010.quadra 470 | ON cnefe2010.setor.idn_setor = cnefe2010.quadra.idn_setor 471 | LEFT JOIN cnefe2010.face 472 | ON cnefe2010.quadra.idn_quadra = cnefe2010.face.idn_quadra 473 | LEFT JOIN cnefe2010.endereco 474 | ON cnefe2010.face.idn_face = cnefe2010.endereco.idn_face 475 | GROUP BY setor.idn_setor, setor.cod_setor, situacao_setor.idn_situacao_setor, situacao_setor.dsc_situacao_setor, 476 | quadra.idn_quadra, quadra.num_quadra, 477 | face.idn_face, num_cep, cep_null 478 | ) as foo 479 | GROUP BY idn_setor, cod_setor, idn_situacao_setor, dsc_situacao_setor, 480 | idn_quadra, num_quadra, 481 | idn_face, cep_null 482 | 483 | --criando a tabela com estatisticas do numero de quadras com 1,2, 3... ceps 484 | select No_ceps_por_face, cep_null, count(*) 485 | from cnefe2010.ceps_by_face 486 | GROUP BY No_ceps_por_face, cep_null 487 | ORDER BY count(*) desc, cep_null 488 | 489 | 490 | 491 | 492 | select cep IS NULL cep_null, count(*) 493 | from teste1.cnefe2010 494 | group by cep_null 495 | #tudo nao nulo, 81550587 496 | 497 | 498 | select num_cep IS NULL cep_null, count(*) 499 | from cnefe2010.endereco 500 | group by cep_null 501 | 502 | select * from cnefe2010.endereco limit 2000 503 | 504 | 505 | 506 | SELECT cep_null, count(*) 507 | FROM 508 | ( 509 | SELECT idn_face, 510 | num_cep, 511 | num_cep IS NULL AS cep_null, 512 | count(*) AS No_end_face_cep 513 | FROM cnefe2010.endereco 514 | GROUP BY idn_face, num_cep, cep_null 515 | ) AS foo 516 | GROUP BY cep_null 517 | 518 | 519 | SELECT count(*) from cnefe2010.uf 520 | # ERROR: could not open file "base/7517593/12281394": Read-only file system 521 | 522 | SELECT count(*) from cnefe2010.municipio 523 | # ERROR: could not open file "base/7517593/12281394": Read-only file system 524 | 525 | SELECT count(*) from cnefe2010.distrito 526 | # ERROR: could not open file "base/7517593/12281394": Read-only file system 527 | 528 | SELECT count(*) from cnefe2010.subdistrito 529 | # ERROR: could not open file "base/7517593/12281394": Read-only file system 530 | 531 | SELECT count(*) from cnefe2010.setor 532 | # 312mil 312244 533 | 534 | SELECT count(*) from cnefe2010.quadra 535 | # 2.1 milhoes 2145264 536 | 537 | SELECT count(*) from cnefe2010.face 538 | # 7.4 milhoes 7404657 539 | 540 | SELECT count(*) from cnefe2010.endereco 541 | # 11.3 milhoes 11330041 542 | 543 | SELECT count(*), count(num_cep) from cnefe2010.endereco 544 | # 11milhoes. 11330041 545 | 546 | SELECT count(*) from cnefe2010.domicilio 547 | #11.3 milhoes 11330041 548 | 549 | 550 | 551 | 552 | 553 | 554 | 555 | 556 | 557 | 558 | 559 | 560 | 561 | 562 | 563 | 564 | 565 | 566 | 567 | 568 | 569 | 570 | 571 | 572 | 573 | 574 | 575 | 576 | 577 | 578 | 579 | 580 | 581 | 582 | 583 | 584 | --------------------------------------------------------------------------------