DECLARE
var_redge RECORD;
var_states text[];
+ var_countyfp text[];
var_addy NORM_ADDY;
var_strnum varchar;
var_nstrnum numeric(10);
RAISE NOTICE 'Get matching states end: %', clock_timestamp();
END IF;
IF array_upper(var_states, 1) IS NULL THEN
- -- We don't have any data for this state
- RETURN;
+ -- We don't have any data for this state
+ RETURN;
+ END IF;
+ var_countyfp := ARRAY(SELECT countyfp FROM county WHERE statefp = ANY(var_states) AND ST_Intersects(the_geom, var_pt) );
+ IF array_upper(var_countyfp, 1) IS NULL THEN
+ -- We don't have any data for this county
+ 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
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.abbrev As 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 (SELECT * FROM edges WHERE statefp = ANY(var_states) ) AS e INNER JOIN (SELECT * FROM state_lookup WHERE statefp = ANY(var_states) ) As s ON (e.statefp = s.statefp )
- INNER JOIN (SELECT * FROM faces WHERE statefp = ANY(var_states) ) As fl ON (e.tfidl = fl.tfid AND e.statefp = fl.statefp)
- INNER JOIN (SELECT * FROM faces WHERE statefp = ANY(var_states) ) As fr ON (e.tfidr = fr.tfid AND e.statefp = fr.statefp)
+ FROM (SELECT * FROM edges WHERE statefp = ANY(var_states) AND countyfp = ANY(var_countyfp) ) AS e INNER JOIN (SELECT * FROM state_lookup WHERE statefp = ANY(var_states) ) As s ON (e.statefp = s.statefp )
+ INNER JOIN (SELECT * FROM faces WHERE statefp = ANY(var_states) AND countyfp = ANY(var_countyfp) ) As fl ON (e.tfidl = fl.tfid AND e.statefp = fl.statefp)
+ INNER JOIN (SELECT * FROM faces WHERE statefp = ANY(var_states) AND countyfp = ANY(var_countyfp) ) As fr ON (e.tfidr = fr.tfid AND e.statefp = fr.statefp)
INNER JOIN (SELECT * FROM addr WHERE statefp = ANY(var_states) ) 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 **/
CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)
);
+CREATE INDEX idx_tiger_data_edges ON edges USING btree (countyfp);
DROP TABLE IF EXISTS state;
CREATE TABLE state
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
);
CREATE INDEX idx_edges_tlid ON edges USING btree(tlid);
+CREATE INDEX idx_tiger_edges_countyfp ON edges USING btree(countyfp);
DROP TABLE IF EXISTS faces;
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4269)
);
CREATE INDEX idx_tiger_faces_tfid ON faces USING btree (tfid);
+CREATE INDEX idx_tiger_faces_countyfp ON faces USING btree(countyfp);
-- Index: tiger.faces_the_geom_gist
'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (gid)) INHERITS(${lookup_name});" ',
'${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_tfid ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (tfid);"
+ ${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_countyfp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (countyfp);"
${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};" ');
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_tlid ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tlid);"
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_tfidr ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tfidr);"
${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_tfidl ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tfidl);"
+${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_countyfp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (countyfp);"
${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${table_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${table_name} USING gist(the_geom);"
${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}_zipl ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (zipl);"
ALTER TABLE state_lookup ADD COLUMN statefp char(2);
UPDATE state_lookup SET statefp = lpad(st_code::text,2,'0') WHERE statefp IS NULL;
ALTER TABLE state_lookup ADD CONSTRAINT state_lookup_statefp_key UNIQUE(statefp);
+CREATE INDEX idx_tiger_edges_countyfp ON edges USING btree(countyfp);
+CREATE INDEX idx_tiger_faces_countyfp ON faces USING btree(countyfp);
BEGIN;
-- Type used to pass around a normalized address between functions