"%PGBIN%\psql" -d "%THEDB%" -c "CREATE SCHEMA tiger_data"\r
"%PGBIN%\psql" -d "%THEDB%" -f "tiger_loader.sql"\r
"%PGBIN%\psql" -d "%THEDB%" -f "create_geocode.sql"\r
+"%PGBIN%\psql" -d "%THEDB%" -c "CREATE INDEX idx_tiger_addr_least_address ON addr USING btree (least_hn(fromhn,tohn));"\r
pause\r
\r
${PSQL_CMD} -d "${THEDB}" -f "tables/lookup_tables_2010.sql"
${PSQL_CMD} -d "${THEDB}" -c "CREATE SCHEMA tiger_data"
${PSQL_CMD} -d "${THEDB}" -f "tiger_loader.sql"
-${PSQL_CMD} -d "${THEDB}" -f "create_geocode.sql"
\ No newline at end of file
+${PSQL_CMD} -d "${THEDB}" -f "create_geocode.sql"
+${PSQL_CMD} -d "${THEDB}" -c "CREATE INDEX idx_tiger_addr_least_address ON addr USING btree (least_hn(fromhn,tohn));"
\ No newline at end of file
-- It also allows us to shorten and possibly better cache the repetitive pattern in the code
-- greatest(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999''))
-- and least(to_number(b.fromhn,''99999999''),to_number(b.tohn,''99999999''))
-CREATE OR REPLACE FUNCTION least_hn(fromhn varchar, tohn varchar)
+CREATE OR REPLACE FUNCTION tiger.least_hn(fromhn varchar, tohn varchar)
RETURNS integer AS
-$$ SELECT least(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$
+$$ SELECT least(to_number( CASE WHEN trim($1) ~ '^[0-9]+$' THEN $1 ELSE '0' END,'99999999'),to_number(CASE WHEN trim($2) ~ '^[0-9]+$' THEN $2 ELSE '0' END,'99999999') )::integer; $$
LANGUAGE sql IMMUTABLE
- COST 1;
+ COST 5;
-- Note we are wrapping this in a function so we can make it immutable (for some reason least and greatest aren't considered immutable)
-- and thu useable in an index or cacheable for multiple calls
CREATE OR REPLACE FUNCTION greatest_hn(fromhn varchar, tohn varchar)
RETURNS integer AS
-$$ SELECT greatest(to_number($1,'99999999'),to_number($2,'99999999') )::integer; $$
+$$ SELECT greatest(to_number( CASE WHEN trim($1) ~ '^[0-9]+$' THEN $1 ELSE '0' END,'99999999'),to_number(CASE WHEN trim($2) ~ '^[0-9]+$' THEN $2 ELSE '0' END,'99999999') )::integer; $$
LANGUAGE sql IMMUTABLE
- COST 1;
+ COST 5;
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
);
+CREATE INDEX tiger_state_the_geom_gist ON faces USING gist(the_geom);
DROP TABLE IF EXISTS place;
CREATE TABLE place
);
CREATE INDEX idx_edges_tlid ON edges USING btree(tlid);
CREATE INDEX idx_tiger_edges_countyfp ON edges USING btree(countyfp);
+CREATE INDEX tiger_edges_the_geom_gist ON edges USING gist(the_geom);
DROP TABLE IF EXISTS faces;
);
CREATE INDEX idx_tiger_faces_tfid ON faces USING btree (tfid);
CREATE INDEX idx_tiger_faces_countyfp ON faces USING btree(countyfp);
+CREATE INDEX tiger_faces_the_geom_gist ON faces USING gist(the_geom);
--- Index: tiger.faces_the_geom_gist
-
--- DROP INDEX tiger.faces_the_geom_gist;
-
-CREATE INDEX tiger_faces_the_geom_gist
- ON faces
- USING gist
- (the_geom);
-
CREATE TABLE featnames
(
gid SERIAL NOT NULL,
'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(${table_name});" ',
'${psql} -c "UPDATE ${data_schema}.${state_abbrev}_${lookup_name} SET statefp = ''${state_fips}'' WHERE statefp IS NULL;"
${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
- ${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_least_address ON tiger_data.ma_addr USING btree (least_hn(fromhn,tohn) );"
+ ${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_least_address ON tiger_data.${state_abbrev}_addr USING btree (least_hn(fromhn,tohn) );"
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_tlid_statefp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tlid, statefp);"
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_zip ON ${data_schema}.${state_abbrev}_${table_name} USING btree (zip);"
${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_zip_state(CONSTRAINT pk_${state_abbrev}_zip_state PRIMARY KEY(zip,stusps)) INHERITS(zip_state); "
CREATE INDEX idx_tiger_edges_countyfp ON edges USING btree(countyfp);
CREATE INDEX idx_tiger_faces_countyfp ON faces USING btree(countyfp);
CREATE INDEX tiger_place_the_geom_gist ON place USING gist(the_geom);
+CREATE INDEX tiger_edges_the_geom_gist ON edges USING gist(the_geom);
+CREATE INDEX tiger_state_the_geom_gist ON faces USING gist(the_geom);
BEGIN;
-- Type used to pass around a normalized address between functions
-- Reverse Geocode API, called by user
\i geocode/reverse_geocode.sql
-COMMIT;
\ No newline at end of file
+COMMIT;
+CREATE INDEX idx_tiger_addr_least_address ON addr USING btree (least_hn(fromhn,tohn));
\ No newline at end of file