1--
2-- PostGIS - Spatial Types for PostgreSQL
3-- http://postgis.net
4--
5-- Copyright (C) 2012-2015 Regina Obe and Leo Hsu
6-- Paragon Corporation
7--
8-- This is free software; you can redistribute and/or modify it under
9-- the terms of the GNU General Public Licence. See the COPYING file.
10--
11-- Author: Regina Obe and Leo Hsu <lr@pcorp.us>
12--
13-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
14SELECT tiger.SetSearchPathForInstall('tiger');
15BEGIN;
16CREATE OR REPLACE FUNCTION create_census_base_tables()
17	RETURNS text AS
18$$
19DECLARE var_temp text;
20BEGIN
21var_temp := tiger.SetSearchPathForInstall('tiger');
22IF NOT EXISTS(SELECT table_name FROM information_schema.columns WHERE table_schema = 'tiger' AND column_name = 'tract_id' AND table_name = 'tract')  THEN
23	-- census block group/tracts parent tables not created yet or an older version -- drop old if not in use, create new structure
24	DROP TABLE IF EXISTS tiger.tract;
25	CREATE TABLE tract
26	(
27	  gid serial NOT NULL,
28	  statefp varchar(2),
29	  countyfp varchar(3),
30	  tractce varchar(6),
31	  tract_id varchar(11) PRIMARY KEY,
32	  name varchar(7),
33	  namelsad varchar(20),
34	  mtfcc varchar(5),
35	  funcstat varchar(1),
36	  aland double precision,
37	  awater double precision,
38	  intptlat varchar(11),
39	  intptlon varchar(12),
40	  the_geom geometry,
41	  CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
42	  CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
43	  CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)
44	);
45
46	DROP TABLE IF EXISTS tiger.tabblock;
47	CREATE TABLE tabblock
48	(
49	  gid serial NOT NULL,
50	  statefp varchar(2),
51	  countyfp varchar(3),
52	  tractce varchar(6),
53	  blockce varchar(4),
54	  tabblock_id varchar(16) PRIMARY KEY,
55	  name varchar(20),
56	  mtfcc varchar(5),
57	  ur varchar(1),
58	  uace varchar(5),
59	  funcstat varchar(1),
60	  aland double precision,
61	  awater double precision,
62	  intptlat varchar(11),
63	  intptlon varchar(12),
64	  the_geom geometry,
65	  CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
66	  CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
67	  CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)
68	);
69
70	DROP TABLE IF EXISTS tiger.bg;
71	CREATE TABLE bg
72	(
73	  gid serial NOT NULL,
74	  statefp varchar(2),
75	  countyfp varchar(3),
76	  tractce varchar(6),
77	  blkgrpce varchar(1),
78	  bg_id varchar(12) PRIMARY KEY,
79	  namelsad varchar(13),
80	  mtfcc varchar(5),
81	  funcstat varchar(1),
82	  aland double precision,
83	  awater double precision,
84	  intptlat varchar(11),
85	  intptlon varchar(12),
86	  the_geom geometry,
87	  CONSTRAINT enforce_dims_geom CHECK (st_ndims(the_geom) = 2),
88	  CONSTRAINT enforce_geotype_geom CHECK (geometrytype(the_geom) = 'MULTIPOLYGON'::text OR the_geom IS NULL),
89	  CONSTRAINT enforce_srid_geom CHECK (st_srid(the_geom) = 4269)
90	);
91	COMMENT ON TABLE tiger.bg IS 'block groups';
92END IF;
93
94IF 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
95    ALTER TABLE tiger.tabblock ALTER COLUMN name TYPE varchar(20);
96    ALTER TABLE tiger.tabblock ALTER COLUMN tabblock_id TYPE varchar(16);
97    RAISE NOTICE 'Size of tabblock_id and name are being increased';
98END IF;
99RETURN 'Tables already present';
100END
101$$
102language 'plpgsql';
103
104CREATE OR REPLACE FUNCTION loader_macro_replace(param_input text, param_keys text[],param_values text[])
105RETURNS text AS
106$$
107	DECLARE var_result text = param_input;
108	DECLARE var_count integer = array_upper(param_keys,1);
109	BEGIN
110		FOR i IN 1..var_count LOOP
111			var_result := replace(var_result, '${' || param_keys[i] || '}', param_values[i]);
112		END LOOP;
113		return var_result;
114	END;
115$$
116  LANGUAGE 'plpgsql' IMMUTABLE
117  COST 100;
118
119-- Helper function that generates script to drop all tables in a particular schema for a particular table
120-- This is useful in case you need to reload a state
121CREATE OR REPLACE FUNCTION drop_state_tables_generate_script(param_state text, param_schema text DEFAULT 'tiger_data')
122  RETURNS text AS
123$$
124SELECT array_to_string(array_agg('DROP TABLE ' || quote_ident(table_schema) || '.' || quote_ident(table_name) || ';'),E'\n')
125	FROM (SELECT * FROM information_schema.tables
126	WHERE table_schema = $2 AND table_name like lower($1) || '_%' ORDER BY table_name) AS foo;
127;
128$$
129  LANGUAGE sql VOLATILE;
130
131-- Helper function that generates script to drop all nation tables (county, state) in a particular schema
132-- This is useful for loading 2011 because state and county tables aren't broken out into separate state files
133DROP FUNCTION IF EXISTS drop_national_tables_generate_script(text);
134CREATE OR REPLACE FUNCTION drop_nation_tables_generate_script(param_schema text DEFAULT 'tiger_data')
135  RETURNS text AS
136$$
137SELECT array_to_string(array_agg('DROP TABLE ' || quote_ident(table_schema) || '.' || quote_ident(table_name) || ';'),E'\n')
138	FROM (SELECT * FROM information_schema.tables
139	WHERE table_schema = $1 AND (table_name ~ E'^[a-z]{2}\_county' or table_name ~ E'^[a-z]{2}\_state' or table_name = 'state_all' or table_name LIKE 'county_all%' or table_name LIKE 'zcta5_all%') ORDER BY table_name) AS foo;
140;
141$$
142  LANGUAGE sql VOLATILE;
143
144DO
145$$
146BEGIN
147  IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_platform' AND table_schema = 'tiger') THEN
148      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);
149  END IF;
150END
151$$ LANGUAGE 'plpgsql';
152
153DO
154$$
155BEGIN
156  IF NOT EXISTS (SELECT * FROM information_schema.schemata WHERE schema_name = 'tiger_data') THEN
157       CREATE SCHEMA tiger_data;
158  END IF;
159END
160$$ LANGUAGE 'plpgsql';
161
162DELETE FROM loader_platform WHERE os IN ('sh', 'windows');
163GRANT SELECT ON TABLE loader_platform TO public;
164INSERT INTO loader_platform(os, wget, pgbin, declare_sect, unzip_command, psql,path_sep,loader, environ_set_command, county_process_command)
165VALUES('windows', '%WGETTOOL%', '%PGBIN%',
166E'set TMPDIR=${staging_fold}\\temp\\
167set UNZIPTOOL="C:\\Program Files\\7-Zip\\7z.exe"
168set WGETTOOL="C:\\wget\\wget.exe"
169set PGBIN=C:\\Program Files\\PostgreSQL\\10\\bin\\
170set PGPORT=5432
171set PGHOST=localhost
172set PGUSER=postgres
173set PGPASSWORD=yourpasswordhere
174set PGDATABASE=geocoder
175set PSQL="%PGBIN%psql"
176set SHP2PGSQL="%PGBIN%shp2pgsql"
177cd ${staging_fold}
178', E'del %TMPDIR%\\*.* /Q
179%PSQL% -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE;"
180%PSQL% -c "CREATE SCHEMA ${staging_schema};"
181%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 $$"
182for /r %%z in (*.zip) do %UNZIPTOOL% e %%z  -o%TMPDIR%
183cd %TMPDIR%', E'%PSQL%', E'\\', E'%SHP2PGSQL%', 'set ',
184'for /r %%z in (*${table_name}*.dbf) do (${loader} -D -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}''));")'
185);
186
187INSERT INTO loader_platform(os, wget, pgbin, declare_sect, unzip_command, psql, path_sep, loader, environ_set_command, county_process_command)
188VALUES('sh', 'wget', '',
189E'TMPDIR="${staging_fold}/temp/"
190UNZIPTOOL=unzip
191WGETTOOL="/usr/bin/wget"
192export PGBIN=/usr/lib/postgresql/10/bin
193export PGPORT=5432
194export PGHOST=localhost
195export PGUSER=postgres
196export PGPASSWORD=yourpasswordhere
197export PGDATABASE=geocoder
198PSQL=${PGBIN}/psql
199SHP2PGSQL=shp2pgsql
200cd ${staging_fold}
201', E'rm -f ${TMPDIR}/*.*
202${PSQL} -c "DROP SCHEMA IF EXISTS ${staging_schema} CASCADE;"
203${PSQL} -c "CREATE SCHEMA ${staging_schema};"
204for z in *.zip; do $UNZIPTOOL -o -d $TMPDIR $z; done
205cd $TMPDIR;\n', '${PSQL}', '/', '${SHP2PGSQL}', 'export ',
206'for z in *${table_name}*.dbf; do
207${loader} -D -s 4269 -g the_geom -W "latin1" $z ${staging_schema}.${state_abbrev}_${table_name} | ${psql}
208${PSQL} -c "SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}''));"
209done');
210
211-- variables table
212DO $$
213BEGIN
214  IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_variables' AND table_schema = 'tiger') THEN
215      CREATE TABLE loader_variables(tiger_year varchar(4) PRIMARY KEY, website_root text, staging_fold text, data_schema text, staging_schema text);
216  END IF;
217END
218$$ LANGUAGE 'plpgsql';
219
220TRUNCATE TABLE loader_variables;
221INSERT INTO loader_variables(tiger_year, website_root , staging_fold, data_schema, staging_schema)
222	VALUES('2017', 'https://www2.census.gov/geo/tiger/TIGER2017', '/gisdata', 'tiger_data', 'tiger_staging');
223GRANT SELECT ON TABLE loader_variables TO public;
224
225DO $$
226BEGIN
227  IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_name = 'loader_lookuptables' AND table_schema = 'tiger') THEN
228   CREATE TABLE loader_lookuptables(process_order integer NOT NULL DEFAULT 1000,
229		lookup_name text primary key,
230		table_name text, single_mode boolean NOT NULL DEFAULT true,
231		load boolean NOT NULL DEFAULT true,
232		level_county boolean NOT NULL DEFAULT false,
233		level_state boolean NOT NULL DEFAULT false,
234		level_nation boolean NOT NULL DEFAULT false,
235		post_load_process text, single_geom_mode boolean DEFAULT false,
236		insert_mode char(1) NOT NULL DEFAULT 'c',
237		pre_load_process text,columns_exclude text[], website_root_override text);
238  END IF;
239END
240$$ LANGUAGE 'plpgsql';
241
242TRUNCATE TABLE loader_lookuptables;
243
244GRANT SELECT ON TABLE loader_lookuptables TO public;
245
246-- put in explanatory comments of what each column is for
247COMMENT ON COLUMN loader_lookuptables.lookup_name IS 'This is the table name to inherit from and suffix of resulting output table -- how the table will be named --  edges here would mean -- ma_edges , pa_edges etc. except in the case of national tables. national level tables have no prefix';
248COMMENT ON COLUMN loader_lookuptables.level_nation IS 'These are tables that contain all data for the whole US so there is just a single file';
249COMMENT ON COLUMN loader_lookuptables.table_name IS 'suffix of the tables to load e.g.  edges would load all tables like *edges.dbf(shp)  -- so tl_2010_42129_edges.dbf .  ';
250COMMENT ON COLUMN loader_lookuptables.load IS 'Whether or not to load the table.  For states and zcta5 (you may just want to download states10, zcta510 nationwide file manually) load your own into a single table that inherits from tiger.states, tiger.zcta5.  You''ll get improved performance for some geocoding cases.';
251COMMENT ON COLUMN loader_lookuptables.columns_exclude IS 'List of columns to exclude as an array. This is excluded from both input table and output table and rest of columns remaining are assumed to be in same order in both tables. gid, geoid,cpi,suffix1ce are excluded if no columns are specified.';
252COMMENT ON COLUMN loader_lookuptables.website_root_override IS 'Path to use for wget instead of that specified in year table.  Needed currently for zcta where they release that only for 2000 and 2010';
253
254INSERT 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 )
255VALUES(10, 'tract', 'tract', true, false, true,false, 'c',
256'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (tract_id) ) INHERITS(tiger.${lookup_name}); " ',
257	'${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${table_name} RENAME geoid TO tract_id;  SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}'')); "
258	${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
259	${psql} -c "VACUUM ANALYZE ${data_schema}.${state_abbrev}_${lookup_name};"
260	${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"', ARRAY['gid']);
261
262INSERT 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 )
263VALUES(11, 'tabblock', 'tabblock10', false, false, true,false, 'c',
264'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (tabblock_id)) INHERITS(tiger.${lookup_name});" ',
265'${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${lookup_name} RENAME geoid10 TO tabblock_id;  SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}'')); "
266${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
267${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
268${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"', '{gid, uatyp10, uatype, suffix1ce}'::text[]);
269
270INSERT 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 )
271VALUES(12, 'bg', 'bg', false,false, true,false, 'c',
272'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (bg_id)) INHERITS(tiger.${lookup_name});" ',
273'${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${table_name} RENAME geoid TO bg_id;  SELECT loader_load_staged_data(lower(''${state_abbrev}_${table_name}''), lower(''${state_abbrev}_${lookup_name}'')); "
274${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
275${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
276${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"', ARRAY['gid']);
277
278INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state,  level_nation, single_geom_mode, pre_load_process, post_load_process)
279VALUES(2, 'county_all', 'county', true, false, false, true,
280	false, '${psql} -c "CREATE TABLE ${data_schema}.${lookup_name}(CONSTRAINT pk_${data_schema}_${lookup_name} PRIMARY KEY (cntyidfp),CONSTRAINT uidx_${data_schema}_${lookup_name}_gid UNIQUE (gid)  ) INHERITS(tiger.county); " ',
281	'${psql} -c "ALTER TABLE ${staging_schema}.${table_name} RENAME geoid TO cntyidfp;  SELECT loader_load_staged_data(lower(''${table_name}''), lower(''${lookup_name}''));"
282	${psql} -c "CREATE INDEX ${data_schema}_${table_name}_the_geom_gist ON ${data_schema}.${lookup_name} USING gist(the_geom);"
283	${psql} -c "CREATE UNIQUE INDEX uidx_${data_schema}_${lookup_name}_statefp_countyfp ON ${data_schema}.${lookup_name} USING btree(statefp,countyfp);"
284	${psql} -c "CREATE TABLE ${data_schema}.${lookup_name}_lookup ( CONSTRAINT pk_${lookup_name}_lookup PRIMARY KEY (st_code, co_code)) INHERITS (tiger.county_lookup);"
285	${psql} -c "VACUUM ANALYZE ${data_schema}.${lookup_name};"
286	${psql} -c "INSERT INTO ${data_schema}.${lookup_name}_lookup(st_code, state, co_code, name) SELECT CAST(s.statefp as integer), s.abbrev, CAST(c.countyfp as integer), c.name FROM ${data_schema}.${lookup_name} As c INNER JOIN state_lookup As s ON s.statefp = c.statefp;"
287	${psql} -c "VACUUM ANALYZE ${data_schema}.${lookup_name}_lookup;" ');
288
289INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state, level_nation, single_geom_mode, insert_mode, pre_load_process, post_load_process )
290VALUES(1, 'state_all', 'state', true, false, false,true,false, 'c',
291	'${psql} -c "CREATE TABLE ${data_schema}.${lookup_name}(CONSTRAINT pk_${lookup_name} PRIMARY KEY (statefp),CONSTRAINT uidx_${lookup_name}_stusps  UNIQUE (stusps), CONSTRAINT uidx_${lookup_name}_gid UNIQUE (gid) ) INHERITS(tiger.state); "',
292	'${psql} -c "SELECT loader_load_staged_data(lower(''${table_name}''), lower(''${lookup_name}'')); "
293	${psql} -c "CREATE INDEX ${data_schema}_${lookup_name}_the_geom_gist ON ${data_schema}.${lookup_name} USING gist(the_geom);"
294	${psql} -c "VACUUM ANALYZE ${data_schema}.${lookup_name}"' );
295
296INSERT 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 )
297VALUES(3, 'place', 'place', true, false, true,false, 'c',
298	'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (plcidfp) ) INHERITS(tiger.place);" ',
299	'${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${table_name} RENAME geoid 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);"
300${psql} -c "CREATE INDEX idx_${state_abbrev}_${lookup_name}_soundex_name ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (soundex(name));"
301${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
302${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"'
303	);
304
305INSERT 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 )
306VALUES(4, 'cousub', 'cousub', true, false, true,false, 'c',
307	'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (cosbidfp), CONSTRAINT uidx_${state_abbrev}_${lookup_name}_gid UNIQUE (gid)) INHERITS(tiger.${lookup_name});" ',
308	'${psql} -c "ALTER TABLE ${staging_schema}.${state_abbrev}_${table_name} RENAME geoid TO cosbidfp;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 chk_statefp CHECK (statefp = ''${state_fips}'');"
309${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${lookup_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
310${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_countyfp ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree(countyfp);"');
311
312INSERT INTO loader_lookuptables(process_order, lookup_name, table_name, load, level_county, level_state, level_nation, single_geom_mode, insert_mode, pre_load_process, post_load_process, columns_exclude )
313VALUES(13, 'zcta5_raw', 'zcta510', false,false, false,true, false, 'c',
314	'${psql} -c "CREATE TABLE ${data_schema}.${lookup_name}( zcta5 character varying(5), classfp character varying(2),mtfcc character varying(5), funcstat character varying(1), aland double precision, awater double precision, intptlat character varying(11), intptlon character varying(12), the_geom geometry(MultiPolygon,4269) );"',
315$post_load$${psql} -c "ALTER TABLE tiger.zcta5 DROP CONSTRAINT IF EXISTS enforce_geotype_the_geom; CREATE TABLE ${data_schema}.zcta5_all(CONSTRAINT pk_zcta5_all PRIMARY KEY (zcta5ce,statefp), CONSTRAINT uidx_${lookup_name}_all_gid UNIQUE (gid)) INHERITS(tiger.zcta5);"
316${psql} -c "SELECT loader_load_staged_data(lower('${table_name}'), lower('${lookup_name}'));"
317${psql} -c "INSERT INTO ${data_schema}.zcta5_all(statefp, zcta5ce, classfp, mtfcc, funcstat, aland, awater, intptlat, intptlon, partflg, the_geom) SELECT  s.statefp, z.zcta5,  z.classfp, z.mtfcc, z.funcstat, z.aland, z.awater, z.intptlat, z.intptlon, CASE WHEN ST_Covers(s.the_geom, z.the_geom) THEN 'N' ELSE 'Y' END, ST_SnapToGrid(ST_Transform(CASE WHEN ST_Covers(s.the_geom, z.the_geom) THEN ST_SimplifyPreserveTopology(ST_Transform(z.the_geom,2163),1000) ELSE ST_SimplifyPreserveTopology(ST_Intersection(ST_Transform(s.the_geom,2163), ST_Transform(z.the_geom,2163)),1000)  END,4269), 0.000001) As geom FROM ${data_schema}.zcta5_raw AS z INNER JOIN tiger.state AS s ON (ST_Covers(s.the_geom, z.the_geom) or ST_Overlaps(s.the_geom, z.the_geom) );"
318	${psql} -c "DROP TABLE ${data_schema}.zcta5_raw; CREATE INDEX idx_${data_schema}_zcta5_all_the_geom_gist ON ${data_schema}.zcta5_all USING gist(the_geom);"$post_load$
319, ARRAY['gid','geoid','geoid10', 'partflg']);
320
321INSERT 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 )
322VALUES(6, 'faces', 'faces', true, true, false,false, 'c',
323	'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${table_name}(CONSTRAINT pk_${state_abbrev}_${lookup_name} PRIMARY KEY (gid)) INHERITS(tiger.${lookup_name});" ',
324	'${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${table_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${lookup_name} USING gist(the_geom);"
325	${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_tfid ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (tfid);"
326	${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_countyfp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (countyfp);"
327	${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
328	${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"');
329
330INSERT 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 )
331VALUES(7, 'featnames', 'featnames', true, true, false,false, 'a',
332'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${table_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(tiger.${table_name});ALTER TABLE ${data_schema}.${state_abbrev}_${table_name} ALTER COLUMN statefp SET DEFAULT ''${state_fips}'';" ',
333'${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_snd_name ON ${data_schema}.${state_abbrev}_${table_name} USING btree (soundex(name));"
334${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_lname ON ${data_schema}.${state_abbrev}_${table_name} USING btree (lower(name));"
335${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_tlid_statefp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tlid,statefp);"
336${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
337${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"', ARRAY['gid','statefp']);
338
339INSERT 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 )
340VALUES(8, 'edges', 'edges', true, true, false,false, 'a',
341'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${table_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(tiger.${table_name});"',
342'${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${table_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
343${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_tlid ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tlid);"
344${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}tfidr ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tfidr);"
345${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_tfidl ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tfidl);"
346${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_countyfp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (countyfp);"
347${psql} -c "CREATE INDEX ${data_schema}_${state_abbrev}_${table_name}_the_geom_gist ON ${data_schema}.${state_abbrev}_${table_name} USING gist(the_geom);"
348${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${lookup_name}_zipl ON ${data_schema}.${state_abbrev}_${lookup_name} USING btree (zipl);"
349${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_zip_state_loc(CONSTRAINT pk_${state_abbrev}_zip_state_loc PRIMARY KEY(zip,stusps,place)) INHERITS(tiger.zip_state_loc);"
350${psql} -c "INSERT INTO ${data_schema}.${state_abbrev}_zip_state_loc(zip,stusps,statefp,place) SELECT DISTINCT e.zipl, ''${state_abbrev}'', ''${state_fips}'', p.name FROM ${data_schema}.${state_abbrev}_edges AS e 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;"
351${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_zip_state_loc_place ON ${data_schema}.${state_abbrev}_zip_state_loc USING btree(soundex(place));"
352${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_zip_state_loc ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
353${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"
354${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_zip_state_loc;"
355${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(tiger.zip_lookup_base);"
356${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 tiger.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;"
357${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_zip_lookup_base ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
358${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));"',  ARRAY['gid', 'geoid','divroad'] );
359
360INSERT 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 )
361VALUES(9, 'addr', 'addr', true, true, false,false, 'a',
362	'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(tiger.${table_name});ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ALTER COLUMN statefp SET DEFAULT ''${state_fips}'';" ',
363	'${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
364	${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) );"
365	${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_tlid_statefp ON ${data_schema}.${state_abbrev}_${table_name} USING btree (tlid, statefp);"
366	${psql} -c "CREATE INDEX idx_${data_schema}_${state_abbrev}_${table_name}_zip ON ${data_schema}.${state_abbrev}_${table_name} USING btree (zip);"
367	${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_zip_state(CONSTRAINT pk_${state_abbrev}_zip_state PRIMARY KEY(zip,stusps)) INHERITS(tiger.zip_state); "
368	${psql} -c "INSERT INTO ${data_schema}.${state_abbrev}_zip_state(zip,stusps,statefp) SELECT DISTINCT zip, ''${state_abbrev}'', ''${state_fips}'' FROM ${data_schema}.${state_abbrev}_${lookup_name} WHERE zip is not null;"
369	${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_zip_state ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
370	${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"',  ARRAY['gid','statefp','fromarmid', 'toarmid']);
371
372INSERT 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 )
373VALUES(9, 'addrfeat', 'addrfeat', false, true, false,true, 'a',
374	'${psql} -c "CREATE TABLE ${data_schema}.${state_abbrev}_${lookup_name}(CONSTRAINT pk_${state_abbrev}_${table_name} PRIMARY KEY (gid)) INHERITS(tiger.${table_name});ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ALTER COLUMN statefp SET DEFAULT ''${state_fips}'';" ',
375	'${psql} -c "ALTER TABLE ${data_schema}.${state_abbrev}_${lookup_name} ADD CONSTRAINT chk_statefp CHECK (statefp = ''${state_fips}'');"
376	${psql} -c "vacuum analyze ${data_schema}.${state_abbrev}_${lookup_name};"',  ARRAY['gid','statefp','fromarmid', 'toarmid']);
377
378CREATE OR REPLACE FUNCTION loader_generate_nation_script(os text)
379  RETURNS SETOF text AS
380$BODY$
381WITH lu AS (SELECT lookup_name, table_name, pre_load_process,post_load_process, process_order, insert_mode, single_geom_mode, level_nation, level_county, level_state
382    FROM  loader_lookuptables
383				WHERE level_nation = true AND load = true)
384SELECT
385	loader_macro_replace(
386		replace(
387			loader_macro_replace(declare_sect
388				, ARRAY['staging_fold', 'website_root', 'psql',  'data_schema', 'staging_schema'],
389				ARRAY[variables.staging_fold, variables.website_root, platform.psql, variables.data_schema, variables.staging_schema]
390			), '/', platform.path_sep) || '
391'  ||
392	-- Nation level files
393	array_to_string( ARRAY(SELECT loader_macro_replace('cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
394' || platform.wget || ' ' || variables.website_root  || '/'
395
396-- hardcoding zcta5 path since doesn't follow convention
397|| upper(CASE WHEN table_name = 'zcta510' THEN 'zcta5' ELSE table_name END)  || '/tl_' || variables.tiger_year || '_us_' || lower(table_name) || '.zip --mirror --reject=html
398'
399|| 'cd ' ||  replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(regexp_replace(variables.website_root, 'http[s]?://', ''),'ftp://','')  || '/'
400-- note have to hard-code folder path for zcta because doesn't follow convention
401|| upper(CASE WHEN table_name = 'zcta510' THEN 'zcta5' ELSE table_name END)  || '
402' || replace(platform.unzip_command, '*.zip', 'tl_*' || table_name || '.zip ') || '
403' || COALESCE(lu.pre_load_process || E'\n', '') || platform.loader || ' -D -' ||  lu.insert_mode || ' -s 4269 -g the_geom '
404		|| CASE WHEN lu.single_geom_mode THEN ' -S ' ELSE ' ' END::text || ' -W "latin1" tl_' || variables.tiger_year
405	|| '_us_' || lu.table_name || '.dbf tiger_staging.' || lu.table_name || ' | '::text || platform.psql
406		|| COALESCE(E'\n' ||
407			lu.post_load_process , '') , ARRAY['loader','table_name', 'lookup_name'], ARRAY[platform.loader, lu.table_name, lu.lookup_name ]
408			)
409				FROM lu
410				ORDER BY process_order, lookup_name), E'\n') ::text
411	, ARRAY['psql', 'data_schema','staging_schema', 'staging_fold', 'website_root'],
412	ARRAY[platform.psql,  variables.data_schema, variables.staging_schema, variables.staging_fold, variables.website_root])
413			AS shell_code
414FROM loader_variables As variables
415	 CROSS JOIN loader_platform As platform
416WHERE platform.os = $1 -- generate script for selected platform
417;
418$BODY$
419  LANGUAGE sql VOLATILE;
420
421CREATE OR REPLACE FUNCTION loader_generate_script(param_states text[], os text)
422  RETURNS SETOF text AS
423$BODY$
424SELECT
425	loader_macro_replace(
426		replace(
427			loader_macro_replace(declare_sect
428				, ARRAY['staging_fold', 'state_fold','website_root', 'psql', 'state_abbrev', 'data_schema', 'staging_schema', 'state_fips'],
429				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]
430			), '/', platform.path_sep) || '
431' ||
432	-- State level files - if an override website is specified we use that instead of variable one
433	array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
434' || platform.wget || ' ' || COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name)  ) || '/tl_' || variables.tiger_year || '_' || s.state_fips || '_' || lower(table_name) || '.zip --mirror --reject=html
435'
436|| 'cd ' ||  replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(regexp_replace(COALESCE(lu.website_root_override, variables.website_root || '/' || upper(lookup_name) ), 'http[s]?://', ''),'ftp://','')    || '
437' || replace(platform.unzip_command, '*.zip', 'tl_' || variables.tiger_year || '_' || s.state_fips || '*_' || table_name || '.zip ') || '
438' ||loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || platform.loader || ' -D -' ||  lu.insert_mode || ' -s 4269 -g the_geom '
439		|| CASE WHEN lu.single_geom_mode THEN ' -S ' ELSE ' ' END::text || ' -W "latin1" tl_' || variables.tiger_year || '_' || s.state_fips
440	|| '_' || lu.table_name || '.dbf tiger_staging.' || lower(s.state_abbrev) || '_' || lu.table_name || ' | '::text || platform.psql
441		|| COALESCE(E'\n' ||
442			lu.post_load_process , '') , ARRAY['loader','table_name', 'lookup_name'], ARRAY[platform.loader, lu.table_name, lu.lookup_name ])
443				FROM loader_lookuptables AS lu
444				WHERE level_state = true AND load = true
445				ORDER BY process_order, lookup_name), E'\n') ::text
446	-- County Level files
447	|| E'\n' ||
448		array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
449' ||
450-- explode county files create wget call for each county file
451array_to_string (ARRAY(SELECT platform.wget || ' --mirror  ' || COALESCE(lu.website_root_override, variables.website_root || '/' || upper(lookup_name)  ) || '/tl_' || variables.tiger_year || '_' || s.state_fips || c.countyfp || '_' || lower(table_name) || '.zip ' || E'\n'  AS county_out
452FROM tiger.county As c
453WHERE c.statefp = s.state_fips), ' ')
454|| 'cd ' ||  replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(regexp_replace(COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name)  || '/'), 'http[s]?://', ''),'ftp://','')  || '
455' || replace(platform.unzip_command, '*.zip', 'tl_*_' || s.state_fips || '*_' || table_name || '*.zip ') || '
456' || loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || COALESCE(county_process_command || E'\n','')
457				|| COALESCE(E'\n' ||lu.post_load_process , '') , ARRAY['loader','table_name','lookup_name'], ARRAY[platform.loader  || ' -D ' || CASE WHEN lu.single_geom_mode THEN ' -S' ELSE ' ' END::text, lu.table_name, lu.lookup_name ])
458				FROM loader_lookuptables AS lu
459				WHERE level_county = true AND load = true
460				ORDER BY process_order, lookup_name), E'\n') ::text
461	, ARRAY['psql', 'data_schema','staging_schema', 'staging_fold', 'state_fold', 'website_root', 'state_abbrev','state_fips'],
462	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])
463			AS shell_code
464FROM loader_variables As variables
465		CROSS JOIN (SELECT name As state, abbrev As state_abbrev, lpad(st_code::text,2,'0') As state_fips,
466			 lpad(st_code::text,2,'0') || '_'
467	|| replace(name, ' ', '_') As state_fold
468FROM state_lookup) As s CROSS JOIN loader_platform As platform
469WHERE $1 @> ARRAY[state_abbrev::text]      -- If state is contained in list of states input generate script for it
470AND platform.os = $2  -- generate script for selected platform
471;
472$BODY$
473  LANGUAGE sql VOLATILE;
474
475CREATE OR REPLACE FUNCTION loader_load_staged_data(param_staging_table text, param_target_table text, param_columns_exclude text[]) RETURNS integer
476AS
477$$
478DECLARE
479	var_sql text;
480	var_staging_schema text; var_data_schema text;
481	var_temp text;
482	var_num_records bigint;
483BEGIN
484-- Add all the fields except geoid and gid
485-- Assume all the columns are in same order as target
486	SELECT staging_schema, data_schema INTO var_staging_schema, var_data_schema FROM loader_variables;
487	var_sql := 'INSERT INTO ' || var_data_schema || '.' || quote_ident(param_target_table) || '(' ||
488			array_to_string(ARRAY(SELECT quote_ident(column_name::text)
489				FROM information_schema.columns
490				 WHERE table_name = param_target_table
491					AND table_schema = var_data_schema
492					AND column_name <> ALL(param_columns_exclude)
493                    ORDER BY column_name ), ',') || ') SELECT '
494					|| array_to_string(ARRAY(SELECT quote_ident(column_name::text)
495				FROM information_schema.columns
496				 WHERE table_name = param_staging_table
497					AND table_schema = var_staging_schema
498					AND column_name <> ALL( param_columns_exclude)
499                    ORDER BY column_name ), ',') ||' FROM '
500					|| var_staging_schema || '.' || param_staging_table || ';';
501	RAISE NOTICE '%', var_sql;
502	EXECUTE (var_sql);
503	GET DIAGNOSTICS var_num_records = ROW_COUNT;
504	SELECT DropGeometryTable(var_staging_schema,param_staging_table) INTO var_temp;
505	RETURN var_num_records;
506END;
507$$
508LANGUAGE 'plpgsql' VOLATILE;
509
510CREATE OR REPLACE FUNCTION loader_load_staged_data(param_staging_table text, param_target_table text)
511RETURNS integer AS
512$$
513-- exclude this set list of columns if no exclusion list is specified
514
515   SELECT  loader_load_staged_data($1, $2,(SELECT COALESCE(columns_exclude,ARRAY['gid', 'geoid','cpi','suffix1ce', 'statefp00', 'statefp10', 'countyfp00','countyfp10'
516   ,'tractce00','tractce10', 'blkgrpce00', 'blkgrpce10', 'blockce00', 'blockce10'
517      , 'cousubfp00', 'submcdfp00', 'conctyfp00', 'placefp00', 'aiannhfp00', 'aiannhce00',
518       'comptyp00', 'trsubfp00', 'trsubce00', 'anrcfp00', 'elsdlea00', 'scsdlea00',
519       'unsdlea00', 'uace00', 'cd108fp', 'sldust00', 'sldlst00', 'vtdst00', 'zcta5ce00',
520       '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))
521$$
522language 'sql' VOLATILE;
523
524CREATE OR REPLACE FUNCTION loader_generate_census_script(param_states text[], os text)
525  RETURNS SETOF text AS
526$$
527SELECT create_census_base_tables();
528SELECT
529	loader_macro_replace(
530		replace(
531			loader_macro_replace(declare_sect
532				, ARRAY['staging_fold', 'state_fold','website_root', 'psql', 'state_abbrev', 'data_schema', 'staging_schema', 'state_fips'],
533				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]
534			), '/', platform.path_sep) || '
535' ||
536	-- State level files - if an override website is specified we use that instead of variable one
537	array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
538' || platform.wget || ' ' || COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name)  ) || '/tl_' || variables.tiger_year || '_' || s.state_fips || '_' || lower(table_name) || '.zip --mirror --reject=html
539'
540|| 'cd ' ||  replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(regexp_replace(COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name) ), 'http[s]+://', ''),'ftp://','')    || '
541' || replace(platform.unzip_command, '*.zip', 'tl_' || variables.tiger_year || '_' || s.state_fips || '*_' || table_name || '.zip ') || '
542' ||loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || platform.loader || ' -D -' ||  lu.insert_mode || ' -s 4269 -g the_geom '
543		|| CASE WHEN lu.single_geom_mode THEN ' -S ' ELSE ' ' END::text || ' -W "latin1" tl_' || variables.tiger_year || '_' || s.state_fips
544	|| '_' || lu.table_name || '.dbf tiger_staging.' || lower(s.state_abbrev) || '_' || lu.table_name || ' | '::text || platform.psql
545		|| COALESCE(E'\n' ||
546			lu.post_load_process , '') , ARRAY['loader','table_name', 'lookup_name'], ARRAY[platform.loader, lu.table_name, lu.lookup_name ])
547				FROM loader_lookuptables AS lu
548				WHERE level_state = true AND lu.lookup_name IN('bg','tract', 'tabblock')
549				ORDER BY process_order, lookup_name), E'\n') ::text
550	-- County Level files
551	|| E'\n' ||
552		array_to_string( ARRAY(SELECT 'cd ' || replace(variables.staging_fold,'/', platform.path_sep) || '
553' ||
554-- explode county files create wget call for each county file
555array_to_string (ARRAY(SELECT platform.wget || ' --mirror  ' || COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name)  ) || '/tl_' || variables.tiger_year || '_' || s.state_fips || c.countyfp || '_' || lower(table_name) || '.zip ' || E'\n'  AS county_out
556FROM tiger.county As c
557WHERE c.statefp = s.state_fips), ' ')
558|| 'cd ' ||  replace(variables.staging_fold,'/', platform.path_sep) || '/' || replace(regexp_replace(COALESCE(lu.website_root_override,variables.website_root || '/' || upper(lookup_name)  || '/'), 'http[s]+://', ''),'ftp://','')  || '
559' || replace(platform.unzip_command, '*.zip', 'tl_*_' || s.state_fips || '*_' || table_name || '*.zip ') || '
560' || loader_macro_replace(COALESCE(lu.pre_load_process || E'\n', '') || COALESCE(county_process_command || E'\n','')
561				|| COALESCE(E'\n' ||lu.post_load_process , '') , ARRAY['loader','table_name','lookup_name'], ARRAY[platform.loader  || ' -D ' || CASE WHEN lu.single_geom_mode THEN ' -S' ELSE ' ' END::text, lu.table_name, lu.lookup_name ])
562				FROM loader_lookuptables AS lu
563				WHERE level_county = true AND lu.lookup_name IN('bg','tract', 'tabblock')
564				ORDER BY process_order, lookup_name), E'\n') ::text
565	, ARRAY['psql', 'data_schema','staging_schema', 'staging_fold', 'state_fold', 'website_root', 'state_abbrev','state_fips'],
566	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])
567			AS shell_code
568FROM loader_variables As variables
569		CROSS JOIN (SELECT name As state, abbrev As state_abbrev, lpad(st_code::text,2,'0') As state_fips,
570			 lpad(st_code::text,2,'0') || '_'
571	|| replace(name, ' ', '_') As state_fold
572FROM state_lookup) As s CROSS JOIN loader_platform As platform
573WHERE $1 @> ARRAY[state_abbrev::text]      -- If state is contained in list of states input generate script for it
574AND platform.os = $2  -- generate script for selected platform
575;
576$$
577  LANGUAGE sql VOLATILE;
578
579SELECT create_census_base_tables();
580COMMIT;
581