From: Regina Obe <lr@pcorp.us> Date: Thu, 22 Aug 2013 03:56:50 +0000 (+0000) Subject: #2441 Tiger geocoder uses new features only available in Postgres 9.3. Changed to... X-Git-Tag: 2.2.0rc1~1395 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=d9cf8b9902f166f9aa628e1b8ccdcbb27f5dd3ac;p=postgis #2441 Tiger geocoder uses new features only available in Postgres 9.3. Changed to not use CREATE .. IF NOT EXISTS and use DO instead. Also revised extension to upgrade loader (it wasn't before) git-svn-id: http://svn.osgeo.org/postgis/trunk@11849 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/extensions/postgis_tiger_geocoder/Makefile.in b/extensions/postgis_tiger_geocoder/Makefile.in index a4538ad79..54baf8ac7 100644 --- a/extensions/postgis_tiger_geocoder/Makefile.in +++ b/extensions/postgis_tiger_geocoder/Makefile.in @@ -45,6 +45,7 @@ sql/$(EXTENSION)--$(EXTVERSION)next--$(EXTVERSION).sql: sql/$(EXTENSION)--$(EXTV #strip CREATE SCHEMA since we force extension # to create schema by setting schema to tiger_geocoder in control sql_bits/tiger_geocoder_minor.sql.in: ../../extras/tiger_geocoder/tiger_2011/utility/set_search_path.sql \ + ../../extras/tiger_geocoder/tiger_2011/tiger_loader_2012.sql \ ../../extras/tiger_geocoder/tiger_2011/utility/utmzone.sql \ ../../extras/tiger_geocoder/tiger_2011/utility/cull_null.sql \ ../../extras/tiger_geocoder/tiger_2011/utility/nullable_levenshtein.sql \ @@ -61,7 +62,7 @@ sql_bits/tiger_geocoder_minor.sql.in: ../../extras/tiger_geocoder/tiger_2011/uti ../../extras/tiger_geocoder/tiger_2011/normalize/normalize_address.sql \ ../../extras/tiger_geocoder/tiger_2011/normalize/pprint_addy.sql \ ../../extras/tiger_geocoder/tiger_2011/pagc_normalize/pagc_tables.sql \ - ../../extras/tiger_geocoder/tiger_2011/pagc_normalize/pagc_normalize_address.sql \ + ../../extras/tiger_geocoder/tiger_2011/pagc_normalize/pagc_normalize_address.sql \ ../../extras/tiger_geocoder/tiger_2011/geocode/other_helper_functions.sql \ ../../extras/tiger_geocoder/tiger_2011/geocode/rate_attributes.sql \ ../../extras/tiger_geocoder/tiger_2011/geocode/includes_address.sql \ @@ -153,11 +154,12 @@ sql/$(EXTENSION)--unpackaged--$(EXTVERSION).sql: sql_bits/tiger_geocoder--unpack #aggregates are special #they can be dropped but we need to remove #them from the extension first -sql/tiger_geocoder_upgrade_minor.sql: sql_bits/tiger_geocoder_minor.sql.in +sql/tiger_geocoder_upgrade_minor.sql: sql_bits/tiger_geocoder_minor.sql.in sed -e '/^\(CREATE\|ALTER\) \(CAST\|TYPE\|TABLE\|SCHEMA\|DOMAIN\|TRIGGER\).*;/d' \ -e '/^\(CREATE\|ALTER\) \(CAST\|TYPE\|TABLE\|SCHEMA\|DOMAIN\|TRIGGER\)/,/\;/d' \ + -e 's/BEGIN;//g' -e 's/COMMIT;//g' \ $< > $@ - + sql_minor_upgrade: ../postgis_extension_helper.sql sql_bits/remove_from_extension.sql.in sql/tiger_geocoder_upgrade_minor.sql sql_bits/mark_editable_objects.sql.in sql_bits/tiger_geocoder_comments.sql ../postgis_extension_helper_uninstall.sql for OLD_VERSION in $(UPGRADEABLE_VERSIONS); do \ cat $^ > sql/$(EXTENSION)--$$OLD_VERSION--$(EXTVERSION).sql; \ diff --git a/extras/tiger_geocoder/tiger_2011/tiger_loader_2012.sql b/extras/tiger_geocoder/tiger_2011/tiger_loader_2012.sql index 9f9e8b2e6..d187585e2 100644 --- a/extras/tiger_geocoder/tiger_2011/tiger_loader_2012.sql +++ b/extras/tiger_geocoder/tiger_2011/tiger_loader_2012.sql @@ -12,8 +12,6 @@ -- Author: Regina Obe and Leo Hsu <lr@pcorp.us> -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - ---SET search_path TO tiger,public; ---ALTER TABLE tiger.faces RENAME cd111fp TO cdfp; SELECT tiger.SetSearchPathForInstall('tiger'); BEGIN; CREATE OR REPLACE FUNCTION loader_macro_replace(param_input text, param_keys text[],param_values text[]) @@ -56,17 +54,23 @@ SELECT array_to_string(array_agg('DROP TABLE ' || quote_ident(table_schema) || ' $$ LANGUAGE sql VOLATILE; +DO +$$ +BEGIN + IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_platform' AND table_schema = 'tiger') THEN + CREATE TABLE loader_platform(os varchar(50) PRIMARY KEY, declare_sect text, pgbin text, wget text, unzip_command text, psql text, path_sep text, loader text, environ_set_command text, county_process_command text); + END IF; +END +$$ LANGUAGE 'plpgsql'; - -DROP TABLE IF EXISTS loader_platform; -CREATE TABLE loader_platform(os varchar(50) PRIMARY KEY, declare_sect text, pgbin text, wget text, unzip_command text, psql text, path_sep text, loader text, environ_set_command text, county_process_command text); +DELETE FROM loader_platform WHERE os IN ('sh', 'windows'); GRANT SELECT ON TABLE loader_platform TO public; INSERT INTO loader_platform(os, wget, pgbin, declare_sect, unzip_command, psql,path_sep,loader, environ_set_command, county_process_command) VALUES('windows', '%WGETTOOL%', '%PGBIN%', E'set TMPDIR=${staging_fold}\\temp\\ set UNZIPTOOL="C:\\Program Files\\7-Zip\\7z.exe" set WGETTOOL="C:\\wget\\wget.exe" -set PGBIN=C:\\Program Files\\PostgreSQL\\8.4\\bin\\ +set PGBIN=C:\\Program Files\\PostgreSQL\\9.2\\bin\\ set PGPORT=5432 set PGHOST=localhost set PGUSER=postgres @@ -76,9 +80,9 @@ set PSQL="%PGBIN%psql" set SHP2PGSQL="%PGBIN%shp2pgsql" cd ${staging_fold} ', E'del %TMPDIR%\\*.* /Q -%PSQL% -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE;" -%PSQL% -c "CREATE SCHEMA IF NOT EXISTS ${staging_schema};" -%PSQL% -c "CREATE SCHEMA IF NOT EXISTS ${data_schema};" +%PSQL% -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE; CREATE SCHEMA ${staging_schema};" +%PSQL% -c "CREATE SCHEMA ${staging_schema};" +%PSQL% -c "DO language ''plpgsql'' $$ BEGIN IF NOT EXISTS (SELECT * FROM information_schema.schemata WHERE schema_name = ''${data_schema}'' ) THEN CREATE SCHEMA ${data_schema}; END IF; END $$" for /r %%z in (*.zip) do %UNZIPTOOL% e %%z -o%TMPDIR% cd %TMPDIR%', E'%PSQL%', E'\\', E'%SHP2PGSQL%', 'set ', 'for /r %%z in (*${table_name}.dbf) do (${loader} -s 4269 -g the_geom -W "latin1" %%z tiger_staging.${state_abbrev}_${table_name} | ${psql} & ${psql} -c "SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}''));")' @@ -100,9 +104,9 @@ PSQL=${PGBIN}/psql SHP2PGSQL=${PGBIN}/shp2pgsql cd ${staging_fold} ', E'rm -f ${TMPDIR}/*.* -${PSQL} -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE;" -${PSQL} -c "CREATE SCHEMA IF NOT EXISTS ${staging_schema};" -${PSQL} -c "CREATE SCHEMA IF NOT EXISTS ${data_schema};" +%PSQL% -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE; CREATE SCHEMA ${staging_schema};" +%PSQL% -c "CREATE SCHEMA ${staging_schema};" +%PSQL% -c "DO language ''plpgsql'' $$ BEGIN IF NOT EXISTS (SELECT * FROM information_schema.schemata WHERE schema_name = ''${data_schema}'' ) THEN CREATE SCHEMA ${data_schema}; END IF; END $$" for z in *.zip; do $UNZIPTOOL -o -d $TMPDIR $z; done for z in */*.zip; do $UNZIPTOOL -o -d $TMPDIR $z; done @@ -113,14 +117,23 @@ ${PSQL} -c "SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name} done'); -- variables table -DROP TABLE IF EXISTS loader_variables; -CREATE TABLE loader_variables(tiger_year varchar(4) PRIMARY KEY, website_root text, staging_fold text, data_schema text, staging_schema text); +DO $$ +BEGIN + IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_variables' AND table_schema = 'tiger') THEN + CREATE TABLE loader_variables(tiger_year varchar(4) PRIMARY KEY, website_root text, staging_fold text, data_schema text, staging_schema text); + END IF; +END +$$ LANGUAGE 'plpgsql'; + +TRUNCATE TABLE loader_variables; INSERT INTO loader_variables(tiger_year, website_root , staging_fold, data_schema, staging_schema) VALUES('2012', 'ftp://ftp2.census.gov/geo/tiger/TIGER2012', '/gisdata', 'tiger_data', 'tiger_staging'); GRANT SELECT ON TABLE loader_variables TO public; -DROP TABLE IF EXISTS loader_lookuptables; -CREATE TABLE loader_lookuptables(process_order integer NOT NULL DEFAULT 1000, +DO $$ +BEGIN + IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_lookuptables' AND table_schema = 'tiger') THEN + CREATE TABLE loader_lookuptables(process_order integer NOT NULL DEFAULT 1000, lookup_name text primary key, table_name text, single_mode boolean NOT NULL DEFAULT true, load boolean NOT NULL DEFAULT true, @@ -129,7 +142,13 @@ CREATE TABLE loader_lookuptables(process_order integer NOT NULL DEFAULT 1000, level_nation boolean NOT NULL DEFAULT false, post_load_process text, single_geom_mode boolean DEFAULT false, insert_mode char(1) NOT NULL DEFAULT 'c', - pre_load_process text,columns_exclude text[], website_root_override text); + pre_load_process text,columns_exclude text[], website_root_override text); + END IF; +END +$$ LANGUAGE 'plpgsql'; + +TRUNCATE TABLE loader_lookuptables; + GRANT SELECT ON TABLE loader_lookuptables TO public; @@ -367,6 +386,7 @@ CREATE OR REPLACE FUNCTION loader_load_staged_data(param_staging_table text, par RETURNS integer AS $$ -- exclude this set list of columns if no exclusion list is specified + SELECT loader_load_staged_data($1, $2,(SELECT COALESCE(columns_exclude,ARRAY['gid', 'geoid','cpi','suffix1ce', 'statefp00', 'statefp10', 'countyfp00','countyfp10' ,'tractce00','tractce10', 'blkgrpce00', 'blkgrpce10', 'blockce00', 'blockce10' , 'cousubfp00', 'submcdfp00', 'conctyfp00', 'placefp00', 'aiannhfp00', 'aiannhce00',