Retrieving detailed building heights from Spanish Cadaster
If you want to work with official buildings data in Spain, you can go to Sede Electrónica del Catastro and download the public available vector there. Within the data package, you’ll find a CONSTRU dataset with building information.
The problem there is taht Spanish Cadaster uses an alphabetic coded heights field. Something like -II+IV+TZA
means 2 under the ground floors, 4 floors and 1 rooftop: so 7 total floors, but only 5 floors over the ground. This function will retrieve the height over the ground so you can make a 3D map like this. So, first of all, we’d need to translate the Roman numbers into Arabic numbers, using a tweaked version of the fromRoman
function that you can find here
CREATE OR REPLACE FUNCTION fromRoman(
IN roman text
)
RETURNS integer AS
$BODY$
DECLARE
sql text;
num integer;
rowcount integer;
input integer;
rec record;
BEGIN
roman := upper(roman);
rowcount := 100;
num := 0;
EXECUTE 'SELECT LENGTH('|| quote_literal(roman) ||')' INTO input;
-- los romanos no tenían cero, pero vamos a darles cancha...
IF roman = 'NULLA' THEN
RETURN 0;
EXIT;
END IF;
WHILE input > 0 AND rowcount > 0 LOOP
sql := 'WITH sistema AS('
|| ' SELECT ''I'' AS symbol, 1 AS DecimalValue'
|| ' UNION ALL SELECT ''IV'', 4'
|| ' UNION ALL SELECT ''V'', 5'
|| ' UNION ALL SELECT ''IX'', 9'
|| ' UNION ALL SELECT ''X'', 10'
|| ' UNION ALL SELECT ''XL'', 40'
|| ' UNION ALL SELECT ''L'', 50'
|| ' UNION ALL SELECT ''XC'', 90'
|| ' UNION ALL SELECT ''C'', 100'
|| ' UNION ALL SELECT ''CD'', 400'
|| ' UNION ALL SELECT ''D'', 500'
|| ' UNION ALL SELECT ''CM'', 900'
|| ' UNION ALL SELECT ''M'', 1000'
|| ' UNION ALL SELECT N''|??'', 5000'
|| ' UNION ALL SELECT N''cc|??'', 10000'
|| ' UNION ALL SELECT N''|???'', 50000'
|| ' UNION ALL SELECT N''ccc|???'', 100000'
|| ' UNION ALL SELECT N''ccc|??????'', 150000'
|| ')'
|| 'SELECT (COALESCE(' || num || ',0) + DecimalValue) as dec, ('
|| input::text || '-LENGTH(symbol)) as len'
|| ' FROM sistema'
|| ' WHERE RIGHT('|| quote_literal(roman) ||', '|| input::text ||') LIKE symbol || ''%'''
|| ' AND '|| input::text ||'-LENgth(symbol)>=0'
|| ' ORDER BY DecimalValue desc LIMIT 1;';
-- raise notice '%', sql;
EXECUTE sql INTO rec;
num = rec.dec;
input := rec.len;
rowcount := rowcount - 1;
END LOOP;
-- EXECUTE 'DROP TABLE IF EXISTS sistema';
IF ROWCOUNT = 0 THEN
RETURN NULL;
ELSE
RETURN num;
END IF;
END;
$BODY$
language 'plpgsql';
Then, the main function:
CREATE OR REPLACE FUNCTION cadasterheight(
IN cadaster text
)
RETURNS integer AS
$BODY$
DECLARE
bloques text[];
codes text;
tipos text[];
tipo text;
sql text;
i integer;
j integer;
chk text;
chk2 text;
alturas integer;
BEGIN
-- eliminamos edificios sin código de alturas
IF cadaster is null OR cadaster = '-' OR cadaster = '?' OR cadaster = '#' THEN
return 0;
END IF;
alturas := 0;
-- uniformamos el código
cadaster := upper(cadaster);
cadaster := regexp_replace(cadaster,'\.','');
-- tipos de plantas constructivas a 9/2/2015
codes := '0,B,T,P,CO,JD,PI,SS,ZD,PRG,MAR,ZBE,DEP,PJE,POR,EPT,YJD,ALT,SOP,ESC,ETQ,TEN,TRF,TZA,VOL,FUT,ZPAV,CONS,GOLF,SILO,RUINA,PRESA,SOLAR,SUELO,PTLAN,HORREO,TERRENY,CAMPING,DARSENA';
EXECUTE 'select regexp_split_to_array('''|| codes ||''','','')' INTO tipos;
-- partimos en bloques del mismo tipo y los recorremos
EXECUTE 'select regexp_split_to_array('''|| cadaster ||''',''\+'')' INTO bloques;
i := array_length(bloques, 1);
WHILE i > 0 LOOP
-- contamos sólo plantas sobre rasante y que contengan datos de altura válidos
SELECT substring(bloques[i] from 1 for 1) INTO chk;
SELECT translate(bloques[i], 'ABCDEFGHIJKLMNOPQRSTUVWXYZ0', '') INTO chk2;
IF bloques[i] is not null AND chk <> '-' AND chk <> '?' AND chk2 = '' THEN
-- buscamos el tipo de planta para cada bloque
tipo := null;
j := array_length(tipos, 1);
WHILE j > 0 AND tipo is null LOOP
EXECUTE 'SELECT '''|| tipos[j] || ''' WHERE ' || quote_literal(bloques[i]) || ' LIKE ''%' || tipos[j] || '''' INTO tipo;
j := j-1;
END LOOP;
-- ya tenemos el tipo, lo quitamos del bloque
IF tipo is not null THEN
bloques[i] := replace(bloques[i] , tipo, '');
IF length(bloques[i]) = 0 THEN
bloques[i] := 'I';
END IF;
END IF;
-- validamos el numeral romano del bloque y consideramos que si es incorrecto, es una planta
SELECT translate(bloques[i], 'IVXLCDM', '') INTO chk2;
IF chk2 <> '' THEN
bloques[i] := 'I';
END IF;
-- y sumamos las alturas
alturas := alturas + fromRoman(bloques[i]);
END IF;
i := i-1;
END LOOP;
return alturas;
END;
$BODY$
language 'plpgsql';
And remember! Everything here is under
``` The MIT License (MIT)
Copyright (c) 2016 Abel Vázquez Montoro
Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the “Software”), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED “AS IS”, WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. ``