From: Regina Obe Date: Sat, 26 Mar 2011 17:43:10 +0000 (+0000) Subject: cleanup change linux to sh. Get rid of some typos in the sh script generator, move... X-Git-Tag: 2.0.0alpha1~1833 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=26ca058f374168ca9ea6692c34f3b6b177c4f580;p=postgis cleanup change linux to sh. Get rid of some typos in the sh script generator, move some more variables to the top for easier setting. Fix some errors in loader_tables preventing some soundex index from being created. Change reverse_geocoder.sql (from utfy-8 (not sure how that happened) git-svn-id: http://svn.osgeo.org/postgis/trunk@6969 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/extras/tiger_geocoder/tiger_2010/README b/extras/tiger_geocoder/tiger_2010/README index 62f0ad0d1..bfffe67cf 100644 --- a/extras/tiger_geocoder/tiger_2010/README +++ b/extras/tiger_geocoder/tiger_2010/README @@ -30,8 +30,15 @@ This will generate a script for each state --To generate a windows script SELECT loader_generate_script(ARRAY['DC','RI'], 'windows'); +If you script disappears without loading anything, most likely one of your path settings is wrong. To troubleshoot run the batch script by +first opening up a commandline and executing the file. + +That will keep the window open for you to see the error. + --To generate a linux script (We haven't tested the linux script yet so may need some changes) -SELECT loader_generate_script(ARRAY['DC','RI'], 'linux'); +SELECT loader_generate_script(ARRAY['DC','RI'], 'sh'); + + 9. Copy and paste the generated script into a .bat or .sh file and put in gisdata folder you created and then run it. diff --git a/extras/tiger_geocoder/tiger_2010/create_geocode.sql b/extras/tiger_geocoder/tiger_2010/create_geocode.sql index bbc1237d6..448a3ce4a 100644 --- a/extras/tiger_geocoder/tiger_2010/create_geocode.sql +++ b/extras/tiger_geocoder/tiger_2010/create_geocode.sql @@ -2,7 +2,7 @@ -- Tiger is where we're going to create the functions, but we need -- the PostGIS functions/types which are in public. SET search_path TO tiger,public; - +BEGIN; -- Type used to pass around a normalized address between functions DROP TYPE IF EXISTS norm_addy CASCADE; CREATE TYPE norm_addy AS ( @@ -53,3 +53,4 @@ CREATE TYPE norm_addy AS ( -- Reverse Geocode API, called by user \i geocode/reverse_geocode.sql +COMMIT; \ No newline at end of file diff --git a/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql b/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql index 720f7691b..6d0abbc17 100644 --- a/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql +++ b/extras/tiger_geocoder/tiger_2010/geocode/reverse_geocode.sql @@ -1,101 +1,101 @@ ---$Id$ - /*** - * - * Copyright (C) 2011 Regina Obe and Leo Hsu (Paragon Corporation) - **/ --- This function given a point try to determine the approximate street address (norm_addy form) --- and array of cross streets, as well as interpolated points along the streets --- Use case example an address at the intersection of 3 streets: SELECT pprint_addy(r.addy[1]) As st1, pprint_addy(r.addy[2]) As st2, pprint_addy(r.addy[3]) As st3, array_to_string(r.street, ',') FROM reverse_geocode(ST_GeomFromText('POINT(-71.057811 42.358274)',4269)) As r; -set search_path=tiger,public; -CREATE OR REPLACE FUNCTION reverse_geocode( - IN pt geometry, - IN include_strnum_range boolean, - OUT intpt geometry[], - OUT addy NORM_ADDY[], - OUT street varchar[] -) RETURNS RECORD -AS $_$ -DECLARE - var_redge RECORD; - var_states text[]; - var_addy NORM_ADDY; - var_strnum varchar; - var_nstrnum numeric(10); - var_primary_line geometry := NULL; - var_primary_dist numeric(10,2) ; - var_pt geometry; -BEGIN - IF pt IS NULL THEN - RETURN; - ELSE - IF ST_SRID(pt) = 4269 THEN - var_pt := pt; - ELSE - var_pt := ST_Transform(pt, 4269); - END IF; - END IF; - -- Determine state tables to check - -- this is needed to take advantage of constraint exclusion - var_states := ARRAY(SELECT statefp FROM state WHERE ST_Intersects(the_geom, var_pt) ); - IF array_upper(var_states, 1) IS NULL THEN - -- We don't have any data for this state - RETURN; - END IF; - - -- Find the street edges that this point is closest to with tolerance of 0.005 but only consider the edge if the point is contained in the right or left face - -- Then order addresses by proximity to road - FOR var_redge IN - SELECT * - FROM (SELECT DISTINCT ON(fullname) foo.fullname, foo.stusps, foo.zip, - (SELECT z.place FROM zip_state_loc AS z WHERE z.zip = foo.zip and z.statefp = foo.statefp LIMIT 1) As place, foo.center_pt, - side, to_number(fromhn, '999999') As fromhn, to_number(tohn, '999999') As tohn, ST_GeometryN(ST_Multi(line),1) As line, foo.dist - FROM - (SELECT e.the_geom As line, e.fullname, a.zip, s.stusps, ST_ClosestPoint(e.the_geom, var_pt) As center_pt, e.statefp, a.side, a.fromhn, a.tohn, ST_Distance_Sphere(e.the_geom, var_pt) As dist - FROM edges AS e INNER JOIN state As s ON (e.statefp = s.statefp AND s.statefp = ANY(var_states) ) - INNER JOIN faces As fl ON (e.tfidl = fl.tfid AND e.statefp = fl.statefp) - INNER JOIN faces As fr ON (e.tfidr = fr.tfid AND e.statefp = fr.statefp) - INNER JOIN addr As a ON ( e.tlid = a.tlid AND e.statefp = a.statefp AND - ( ( ST_Covers(fl.the_geom, var_pt) AND a.side = 'L') OR ( ST_Covers(fr.the_geom, var_pt) AND a.side = 'R' ) ) ) - -- INNER JOIN zip_state_loc As z ON (a.statefp = z.statefp AND a.zip = z.zip) /** really slow with this join **/ - WHERE e.statefp = ANY(var_states) AND a.statefp = ANY(var_states) AND ST_DWithin(e.the_geom, var_pt, 0.005) - ORDER BY ST_Distance_Sphere(e.the_geom, var_pt) LIMIT 4) As foo - WHERE dist < 150 --less than 150 m - ORDER BY foo.fullname, foo.dist) As f ORDER BY f.dist LOOP - IF var_primary_line IS NULL THEN --this is the first time in the loop and our primary guess - var_primary_line := var_redge.line; - var_primary_dist := var_redge.dist; - END IF; - -- We only consider other edges as matches if they intersect our primary edge -- that would mean we are at a corner place - IF ST_Intersects(var_redge.line, var_primary_line) THEN - intpt := array_append(intpt,var_redge.center_pt); - IF var_redge.fullname IS NOT NULL THEN - street := array_append(street, (CASE WHEN include_strnum_range THEN COALESCE(var_redge.fromhn::varchar, '')::varchar || ' - ' || COALESCE(var_redge.tohn::varchar,'')::varchar || ' '::varchar ELSE '' END::varchar || var_redge.fullname::varchar)::varchar); - --interploate the number -- note that if fromhn > tohn we will be subtracting which is what we want - -- We only consider differential distances are reeally close from our primary pt - IF var_redge.dist < var_primary_dist*1.1 THEN - var_nstrnum := (var_redge.fromhn + ST_Line_Locate_Point(var_redge.line, var_pt)*(var_redge.tohn - var_redge.fromhn))::numeric(10); - -- The odd even street number side of street rule - IF (var_nstrnum % 2) != (var_redge.tohn % 2) THEN - var_nstrnum := CASE WHEN var_nstrnum + 1 NOT BETWEEN var_redge.fromhn AND var_redge.tohn THEN var_nstrnum - 1 ELSE var_nstrnum + 1 END; - END IF; - var_strnum := var_nstrnum::varchar; - var_addy := normalize_address( COALESCE(var_strnum::varchar || ' ', '') || var_redge.fullname || ', ' || var_redge.place || ', ' || var_redge.stusps || ' ' || var_redge.zip); - addy := array_append(addy, var_addy); - END IF; - END IF; - END IF; - END LOOP; - - RETURN; -END; -$_$ LANGUAGE plpgsql STABLE; - -CREATE OR REPLACE FUNCTION reverse_geocode(IN pt geometry, OUT intpt geometry[], - OUT addy NORM_ADDY[], - OUT street varchar[]) RETURNS RECORD -AS -$$ --- default to not including street range in cross streets -SELECT reverse_geocode($1,false); -$$ +--$Id$ + /*** + * + * Copyright (C) 2011 Regina Obe and Leo Hsu (Paragon Corporation) + **/ +-- This function given a point try to determine the approximate street address (norm_addy form) +-- and array of cross streets, as well as interpolated points along the streets +-- Use case example an address at the intersection of 3 streets: SELECT pprint_addy(r.addy[1]) As st1, pprint_addy(r.addy[2]) As st2, pprint_addy(r.addy[3]) As st3, array_to_string(r.street, ',') FROM reverse_geocode(ST_GeomFromText('POINT(-71.057811 42.358274)',4269)) As r; +--set search_path=tiger,public; +CREATE OR REPLACE FUNCTION reverse_geocode( + IN pt geometry, + IN include_strnum_range boolean, + OUT intpt geometry[], + OUT addy NORM_ADDY[], + OUT street varchar[] +) RETURNS RECORD +AS $_$ +DECLARE + var_redge RECORD; + var_states text[]; + var_addy NORM_ADDY; + var_strnum varchar; + var_nstrnum numeric(10); + var_primary_line geometry := NULL; + var_primary_dist numeric(10,2) ; + var_pt geometry; +BEGIN + IF pt IS NULL THEN + RETURN; + ELSE + IF ST_SRID(pt) = 4269 THEN + var_pt := pt; + ELSE + var_pt := ST_Transform(pt, 4269); + END IF; + END IF; + -- Determine state tables to check + -- this is needed to take advantage of constraint exclusion + var_states := ARRAY(SELECT statefp FROM state WHERE ST_Intersects(the_geom, var_pt) ); + IF array_upper(var_states, 1) IS NULL THEN + -- We don't have any data for this state + RETURN; + END IF; + + -- Find the street edges that this point is closest to with tolerance of 0.005 but only consider the edge if the point is contained in the right or left face + -- Then order addresses by proximity to road + FOR var_redge IN + SELECT * + FROM (SELECT DISTINCT ON(fullname) foo.fullname, foo.stusps, foo.zip, + (SELECT z.place FROM zip_state_loc AS z WHERE z.zip = foo.zip and z.statefp = foo.statefp LIMIT 1) As place, foo.center_pt, + side, to_number(fromhn, '999999') As fromhn, to_number(tohn, '999999') As tohn, ST_GeometryN(ST_Multi(line),1) As line, foo.dist + FROM + (SELECT e.the_geom As line, e.fullname, a.zip, s.stusps, ST_ClosestPoint(e.the_geom, var_pt) As center_pt, e.statefp, a.side, a.fromhn, a.tohn, ST_Distance_Sphere(e.the_geom, var_pt) As dist + FROM edges AS e INNER JOIN state As s ON (e.statefp = s.statefp AND s.statefp = ANY(var_states) ) + INNER JOIN faces As fl ON (e.tfidl = fl.tfid AND e.statefp = fl.statefp) + INNER JOIN faces As fr ON (e.tfidr = fr.tfid AND e.statefp = fr.statefp) + INNER JOIN addr As a ON ( e.tlid = a.tlid AND e.statefp = a.statefp AND + ( ( ST_Covers(fl.the_geom, var_pt) AND a.side = 'L') OR ( ST_Covers(fr.the_geom, var_pt) AND a.side = 'R' ) ) ) + -- INNER JOIN zip_state_loc As z ON (a.statefp = z.statefp AND a.zip = z.zip) /** really slow with this join **/ + WHERE e.statefp = ANY(var_states) AND a.statefp = ANY(var_states) AND ST_DWithin(e.the_geom, var_pt, 0.005) + ORDER BY ST_Distance_Sphere(e.the_geom, var_pt) LIMIT 4) As foo + WHERE dist < 150 --less than 150 m + ORDER BY foo.fullname, foo.dist) As f ORDER BY f.dist LOOP + IF var_primary_line IS NULL THEN --this is the first time in the loop and our primary guess + var_primary_line := var_redge.line; + var_primary_dist := var_redge.dist; + END IF; + -- We only consider other edges as matches if they intersect our primary edge -- that would mean we are at a corner place + IF ST_Intersects(var_redge.line, var_primary_line) THEN + intpt := array_append(intpt,var_redge.center_pt); + IF var_redge.fullname IS NOT NULL THEN + street := array_append(street, (CASE WHEN include_strnum_range THEN COALESCE(var_redge.fromhn::varchar, '')::varchar || ' - ' || COALESCE(var_redge.tohn::varchar,'')::varchar || ' '::varchar ELSE '' END::varchar || var_redge.fullname::varchar)::varchar); + --interploate the number -- note that if fromhn > tohn we will be subtracting which is what we want + -- We only consider differential distances are reeally close from our primary pt + IF var_redge.dist < var_primary_dist*1.1 THEN + var_nstrnum := (var_redge.fromhn + ST_Line_Locate_Point(var_redge.line, var_pt)*(var_redge.tohn - var_redge.fromhn))::numeric(10); + -- The odd even street number side of street rule + IF (var_nstrnum % 2) != (var_redge.tohn % 2) THEN + var_nstrnum := CASE WHEN var_nstrnum + 1 NOT BETWEEN var_redge.fromhn AND var_redge.tohn THEN var_nstrnum - 1 ELSE var_nstrnum + 1 END; + END IF; + var_strnum := var_nstrnum::varchar; + var_addy := normalize_address( COALESCE(var_strnum::varchar || ' ', '') || var_redge.fullname || ', ' || var_redge.place || ', ' || var_redge.stusps || ' ' || var_redge.zip); + addy := array_append(addy, var_addy); + END IF; + END IF; + END IF; + END LOOP; + + RETURN; +END; +$_$ LANGUAGE plpgsql STABLE; + +CREATE OR REPLACE FUNCTION reverse_geocode(IN pt geometry, OUT intpt geometry[], + OUT addy NORM_ADDY[], + OUT street varchar[]) RETURNS RECORD +AS +$$ +-- default to not including street range in cross streets +SELECT reverse_geocode($1,false); +$$ language sql STABLE; \ No newline at end of file diff --git a/extras/tiger_geocoder/tiger_2010/tiger_loader.sql b/extras/tiger_geocoder/tiger_2010/tiger_loader.sql index 3e9aec3b5..5c6107353 100644 --- a/extras/tiger_geocoder/tiger_2010/tiger_loader.sql +++ b/extras/tiger_geocoder/tiger_2010/tiger_loader.sql @@ -1,6 +1,7 @@ --$Id$ SET search_path TO tiger,public; - +SET standard_conforming_string on; +BEGIN; DROP AGGREGATE IF EXISTS array_accum(anyelement); CREATE AGGREGATE array_accum(anyelement) ( SFUNC=array_append, @@ -29,42 +30,46 @@ E'set STATEDIR="${staging_fold}\\${website_root}\\${state_fold}" 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\\8.4\\bin\\ set PGPORT=5432 set PGHOST=localhost set PGUSER=postgres set PGPASSWORD=yourpasswordhere set PGDATABASE=geocoder +set PSQL="%PGBIN%psql" +set SHP2PGSQL="%PGBIN%shp2pgsql" ', E'del %TMPDIR%\\*.* /Q -%PGBIN%\psql -c "DROP SCHEMA ${staging_schema} CASCADE;" -%PGBIN%\psql -c "CREATE SCHEMA ${staging_schema};" +%PSQL% -c "DROP SCHEMA ${staging_schema} CASCADE;" +%PSQL% -c "CREATE SCHEMA ${staging_schema};" cd %STATEDIR% for /r %%z in (*.zip) do %UNZIPTOOL% e %%z -o%TMPDIR% -cd %TMPDIR%', E'%PGBIN%\\psql', E'\\', E'%PGBIN%\\shp2pgsql', 'set ', +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}''));")' ); INSERT INTO loader_platform(os, wget, pgbin, declare_sect, unzip_command, psql, path_sep, loader, environ_set_command, county_process_command) -VALUES('linux', 'wget', '', +VALUES('sh', 'wget', '', E'STATEDIR="${staging_fold}/${website_root}/${state_fold}" -TMPDIR="${staging_fold}/temp/ +TMPDIR="${staging_fold}/temp/" UNZIPTOOL=unzip PGPORT=5432 PGHOST=localhost PGUSER=postgres PGPASSWORD=yourpasswordhere PGDATABASE=geocoder +PSQL=psql +SHP2PGSQ=shp2pgsql ', E'rm -f ${TMPDIR}/*.* -%PGBIN%\psql -c "DROP SCHEMA tiger_staging CASCADE;" -%PGBIN%\psql -c "CREATE SCHEMA tiger_staging;" +${PSQL} -c "DROP SCHEMA tiger_staging CASCADE;" +${PSQL} -c "CREATE SCHEMA tiger_staging;" cd $STATEDIR for z in *.zip do $UNZIPTOOL -o -d $TMPDIR $z for z in */*.zip do $UNZIPTOOL -o -d $TMPDIR $z -cd $TMPDIR', 'psql', '/', 'shp2pgsql', 'export ', -'for z in ${table_name}.dbf do +cd $TMPDIR', '${PSQL}', '/', '${SHP2PGSQL}', 'export ', +'for z in *${table_name}.dbf do ${loader} -s 4269 -g the_geom -W "latin1" $z ${staging_schema}.${state_abbrev}_${table_name} | ${psql} -${psql} -c "SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}''));" +${PSQL} -c "SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}''));" done'); -- variables table DROP TABLE IF EXISTS loader_variables; @@ -101,7 +106,7 @@ INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, le VALUES(3, 'place', 'place10', true, false, true,false, 'c', '${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (plcidfp) ) INHERITS(place);" ', '${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${table_name} RENAME geoid10 TO plcidfp;SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}'')); ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT uidx_${state_abbrev}_${lookup_name}_gid UNIQUE (gid);" -${psql} -c "CREATE INDEX idx_${state_abbrev}_${lookup_name}_soundex_name ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (soundex(name));' +${psql} -c "CREATE INDEX idx_${state_abbrev}_${lookup_name}_soundex_name ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (soundex(name));" ' ); INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state, single_geom_mode, insert_mode, pre_load_process, post_load_process ) @@ -125,7 +130,6 @@ VALUES(6, 'faces', 'faces', true, true, false,false, 'c', ${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');" ${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};" '); - INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state, single_geom_mode, insert_mode, pre_load_process, post_load_process, columns_exclude ) VALUES(7, 'featnames', 'featnames', true, true, false,false, 'a', '${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${table_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(${table_name});" ', @@ -155,7 +159,7 @@ ${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_zip_state_loc;" ${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_zip_lookup_base(CONSTRAINT pk_${state_abbrev}_zip_state_loc_city PRIMARY KEY(zip,state, county, city, statefp)) INHERITS(zip_lookup_base);" ${psql} -c "INSERT INTO ${data_schema}.${state_abbrev}_zip_lookup_base(zip,state,county,city, statefp) SELECT DISTINCT e.zipl, ''${state_abbrev}'', c.name,p.name,''${state_fips}'' FROM ${data_schema}.${state_abbrev}_edges AS e INNER JOIN ${data_schema}.${state_abbrev}_county As c ON (e.countyfp = c.countyfp AND e.statefp = c.statefp AND e.statefp = ''${state_fips}'') INNER JOIN ${data_schema}.${state_abbrev}_faces AS f ON (e.tfidl = f.tfid OR e.tfidr = f.tfid) INNER JOIN ${data_schema}.${state_abbrev}_place As p ON(f.statefp = p.statefp AND f.placefp = p.placefp ) WHERE e.zipl IS NOT NULL;" ${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_zip_lookup_base ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');" -${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_zip_lookup_base_citysnd ON ${data_schema}.${state_abbrev}_zip_lookup_base USING btree(soundex(city));'); +${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_zip_lookup_base_citysnd ON ${data_schema}.${state_abbrev}_zip_lookup_base USING btree(soundex(city));" '); INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state, single_geom_mode, insert_mode, pre_load_process, post_load_process,columns_exclude ) VALUES(9, 'addr', 'addr', true, true, false,false, 'a', @@ -255,4 +259,5 @@ RETURNS integer AS $$ SELECT loader_load_staged_data($1, $2,(SELECT COALESCE(columns_exclude,ARRAY['gid', 'geoid10','cpi','suffix1ce']) FROM loader_lookuptables WHERE $2 LIKE '%' || lookup_name)) $$ -language 'sql' VOLATILE; \ No newline at end of file +language 'sql' VOLATILE; +COMMIT; \ No newline at end of file