-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
SELECT tiger.SetSearchPathForInstall('tiger');
BEGIN;
+CREATE OR REPLACE FUNCTION create_census_base_tables()
+ RETURNS text AS
+$$
+DECLARE var_temp text;
+BEGIN
+var_temp := tiger.SetSearchPathForInstall('tiger');
+IF NOT EXISTS(SELECT table_name FROM information_schema.columns WHERE table_schema = 'tiger' AND column_name = 'tract_id' AND table_name = 'tract') THEN
+ -- census block group/tracts parent tables not created yet or an older version -- drop old if not in use, create new structure
+ DROP TABLE IF EXISTS tiger.tract;
+ CREATE TABLE tract
+ (
+ gid serial NOT NULL,
+ statefp varchar(2),
+ countyfp varchar(3),
+ tractce varchar(6),
+ tract_id varchar(11) PRIMARY KEY,
+ name varchar(7),
+ namelsad varchar(20),
+ mtfcc varchar(5),
+ funcstat varchar(1),
+ aland double precision,
+ awater double precision,
+ intptlat varchar(11),
+ intptlon varchar(12),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
+ 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)
+ );
+
+ DROP TABLE IF EXISTS tiger.tabblock;
+ CREATE TABLE tabblock
+ (
+ gid serial NOT NULL,
+ statefp varchar(2),
+ countyfp varchar(3),
+ tractce varchar(6),
+ blockce varchar(4),
+ tabblock_id varchar(16) PRIMARY KEY,
+ name varchar(20),
+ mtfcc varchar(5),
+ ur varchar(1),
+ uace varchar(5),
+ funcstat varchar(1),
+ aland double precision,
+ awater double precision,
+ intptlat varchar(11),
+ intptlon varchar(12),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
+ 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)
+ );
+
+ DROP TABLE IF EXISTS tiger.bg;
+ CREATE TABLE bg
+ (
+ gid serial NOT NULL,
+ statefp varchar(2),
+ countyfp varchar(3),
+ tractce varchar(6),
+ blkgrpce varchar(1),
+ bg_id varchar(12) PRIMARY KEY,
+ namelsad varchar(13),
+ mtfcc varchar(5),
+ funcstat varchar(1),
+ aland double precision,
+ awater double precision,
+ intptlat varchar(11),
+ intptlon varchar(12),
+ the_geom geometry,
+ CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
+ 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)
+ );
+ COMMENT ON TABLE tiger.bg IS 'block groups';
+END IF;
+
+IF EXISTS(SELECT * FROM information_schema.columns WHERE table_schema = 'tiger' AND column_name = 'tabblock_id' AND table_name = 'tabblock' AND character_maximum_length < 16) THEN -- size of name and tabblock_id fields need to be increased
+ ALTER TABLE tiger.tabblock ALTER COLUMN name TYPE varchar(20);
+ ALTER TABLE tiger.tabblock ALTER COLUMN tabblock_id TYPE varchar(16);
+ RAISE NOTICE 'Size of tabblock_id and name are being incrreased';
+END IF;
+RETURN 'Tables already present';
+END
+$$
+language 'plpgsql';
+
CREATE OR REPLACE FUNCTION loader_macro_replace(param_input text, param_keys text[],param_values text[])
RETURNS text AS
$$
'tazce00', 'ugace00', 'puma5ce00','vtdst10','tazce10','uace10','puma5ce10','tazce', 'uace', 'vtdst', 'zcta5ce', 'zcta5ce10', 'puma5ce', 'ugace10','pumace10', 'estatefp', 'ugace', 'blockce']) FROM loader_lookuptables WHERE $2 LIKE '%' || lookup_name))
$$
language 'sql' VOLATILE;
+
+CREATE OR REPLACE FUNCTION loader_generate_census_script(param_states text[], os text)
+ RETURNS SETOF text AS
+$$
+SELECT create_census_base_tables();
+SELECT
+ loader_macro_replace(
+ replace(
+ loader_macro_replace(declare_sect
+ , ARRAY['staging_fold', 'state_fold','website_root', 'psql', 'state_abbrev', 'data_schema', 'staging_schema', 'state_fips'],
+ ARRAY[variables.staging_fold, s.state_fold, variables.website_root, platform.psql, s.state_abbrev, variables.data_schema, variables.staging_schema, s.state_fips::text]
+ ), '/', platform.path_sep) || '
+' ||
+ -- State level files - if an override website is specified we use that instead of variable one
+ array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
+' || platform.wget || ' ' || COALESCE(lu.website_root_override,variables.website_root || '/' || upper(table_name) ) || '/*_' || s.state_fips || '* --no-parent --relative --recursive --level=2 --accept=zip --mirror --reject=html
+'
+|| 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(replace(COALESCE(lu.website_root_override,variables.website_root || '/' || upper(table_name) ), 'http://', ''),'ftp://','') || '
+' || replace(platform.unzip_command, '*.zip', 'tl_*_' || s.state_fips || '*_' || table_name || '.zip ') || '
+' ||loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || platform.loader || ' -' || lu.insert_mode || ' -s 4269 -g the_geom '
+ || CASE WHEN lu.single_geom_mode THEN ' -S ' ELSE ' ' END::text || ' -W "latin1" tl_' || variables.tiger_year || '_' || s.state_fips
+ || '_' || lu.table_name || '.dbf tiger_staging.' || lower(s.state_abbrev) || '_' || lu.table_name || ' | '::text || platform.psql
+ || COALESCE(E'\n' ||
+ lu.post_load_process , '') , ARRAY['loader','table_name', 'lookup_name'], ARRAY[platform.loader, lu.table_name, lu.lookup_name ])
+ FROM loader_lookuptables AS lu
+ WHERE level_state = true AND load = true AND lookup_name IN('tract','bg','tabblock')
+ ORDER BY process_order, lookup_name), E'\n') ::text
+ -- County Level files
+ || E'\n' ||
+ array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
+' || platform.wget || ' ' || COALESCE(lu.website_root_override,variables.website_root || '/' || upper(table_name) ) || '/*_' || s.state_fips || '* --no-parent --relative --recursive --level=2 --accept=zip --mirror --reject=html
+'
+|| 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(replace(COALESCE(lu.website_root_override,variables.website_root || '/' || upper(table_name) || '/'), 'http://', ''),'ftp://','') || '
+' || replace(platform.unzip_command, '*.zip', 'tl_*_' || s.state_fips || '*_' || table_name || '*.zip ') || '
+' || loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || COALESCE(county_process_command || E'\n','')
+ || COALESCE(E'\n' ||lu.post_load_process , '') , ARRAY['loader','table_name','lookup_name'], ARRAY[platform.loader || CASE WHEN lu.single_geom_mode THEN ' -S' ELSE ' ' END::text, lu.table_name, lu.lookup_name ])
+ FROM loader_lookuptables AS lu
+ WHERE level_county = true AND load = true AND lookup_name IN('tract','bg','tabblock')
+ ORDER BY process_order, lookup_name), E'\n') ::text
+ , ARRAY['psql', 'data_schema','staging_schema', 'staging_fold', 'state_fold', 'website_root', 'state_abbrev','state_fips'],
+ ARRAY[platform.psql, variables.data_schema, variables.staging_schema, variables.staging_fold, s.state_fold,variables.website_root, s.state_abbrev, s.state_fips::text])
+ AS shell_code
+FROM loader_variables As variables
+ CROSS JOIN (SELECT name As state, abbrev As state_abbrev, lpad(st_code::text,2,'0') As state_fips,
+ lpad(st_code::text,2,'0') || '_'
+ || replace(name, ' ', '_') As state_fold
+FROM state_lookup) As s CROSS JOIN loader_platform As platform
+WHERE $1 @> ARRAY[state_abbrev::text] -- If state is contained in list of states input generate script for it
+AND platform.os = $2 -- generate script for selected platform
+;
+$$
+ LANGUAGE sql VOLATILE;
+
+SELECT create_census_base_tables();
COMMIT;
\ No newline at end of file