Skip to content

Commit

Permalink
Added explict column list to INSERTs in preparation for adding geomet…
Browse files Browse the repository at this point in the history
…ry columns (which would screw up implicit column list since raw Census files lack geometry).
  • Loading branch information
leehach committed Nov 10, 2013
1 parent 1d95476 commit 4b4a0ed
Showing 1 changed file with 104 additions and 28 deletions.
132 changes: 104 additions & 28 deletions meta-scripts/Data Store Table-Based.sql
@@ -1,6 +1,35 @@
SET search_path = public;

--CREATE DDL FOR STORAGE BY SEQUENCE
DROP FUNCTION IF EXISTS sql_drop_storage_tables(boolean);
CREATE FUNCTION sql_drop_storage_tables(exec boolean = FALSE) RETURNS text AS $function$
DECLARE
sql TEXT := '';
sql_estimate text;
sql_moe text;
BEGIN
SELECT array_to_string(array_agg(sql1), E'\n'), array_to_string(array_agg(sql2), E'\n')
INTO sql_estimate, sql_moe
FROM (
SELECT
seq,
'DROP TABLE IF EXISTS ' || seq_id || E' CASCADE;' AS sql1,
'DROP TABLE IF EXISTS ' || seq_id || E'_moe CASCADE;' AS sql2
FROM vw_sequence
ORDER BY seq
) s
;

sql := sql_estimate || E'\n\n' || sql_moe;
IF exec THEN
EXECUTE sql;
RETURN 'Success!';
ELSE
RETURN sql;
END IF;
END;
$function$ LANGUAGE plpgsql;

DROP FUNCTION IF EXISTS sql_store_by_tables(boolean);
CREATE FUNCTION sql_store_by_tables(exec boolean = FALSE) RETURNS text AS $function$
DECLARE
Expand Down Expand Up @@ -132,42 +161,89 @@ BEGIN
END;
$function$ LANGUAGE plpgsql;

DROP FUNCTION IF EXISTS sql_insert_into_tables(boolean, text);
CREATE FUNCTION sql_insert_into_tables(exec boolean = FALSE, actions text = 'em') RETURNS text AS $function$
DROP FUNCTION IF EXISTS sql_insert_into_tables(boolean, int[], text);
CREATE FUNCTION sql_insert_into_tables(exec boolean = FALSE, seq_criteria int[] = ARRAY[-1], actions text = 'em') RETURNS text AS $function$
DECLARE
sql TEXT := '';
sql_estimate TEXT;
sql_moe TEXT;
seq_criteria2 int[];
BEGIN
IF seq_criteria = ARRAY[-1] THEN
seq_criteria2 := (SELECT array_agg(seq) FROM vw_sequence);
ELSE
seq_criteria2 := seq_criteria;
END IF;

SELECT array_to_string(array_agg(sql1), E'\n'), array_to_string(array_agg(sql2), E'\n')
INTO sql_estimate, sql_moe
FROM (
SELECT
seq,
CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
'INSERT INTO ' || seq_id ||
E'\nSELECT fileid, filetype, upper(stusab), chariter, seq, logrecno::int,\n'
ELSE ''
END ||
E'\tNULLIF(NULLIF(' || cell_id || E', \'\'), \'.\')::double precision' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\nFROM tmp_' || seq_id || ';'
ELSE ','
END AS sql1,
CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
'INSERT INTO ' || seq_id ||
E'_moe\nSELECT fileid, filetype, upper(stusab), chariter, seq, logrecno::int,\n'
ELSE ''
END ||
E'\tNULLIF(NULLIF(' || cell_id || E'_moe, \'\'), \'.\')::double precision' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\nFROM tmp_' || seq_id || '_moe;'
ELSE ','
END AS sql2
FROM
vw_cell
ORDER BY seq, seq_position
) s
SELECT
seq,
array_to_string(array_agg(insert_list_estimate), E'\n') || E'\n' || array_to_string(array_agg(values_list_estimate), E'\n') AS sql1,
array_to_string(array_agg(insert_list_moe), E'\n') || E'\n' || array_to_string(array_agg(values_list_moe), E'\n') AS sql2
FROM (
SELECT
seq,
CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
'INSERT INTO ' || seq_id || ' (' ||
E'\n\tfileid, filetype, stusab, chariter, seq, logrecno,\n'
ELSE ''
END ||
E'\t' || cell_id ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\n)'
ELSE ','
END AS insert_list_estimate,

CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
E'SELECT fileid, filetype, upper(stusab), chariter, seq, logrecno::int,\n'
ELSE ''
END ||
E'\tNULLIF(NULLIF(' || cell_id || E', \'\'), \'.\')::double precision' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\nFROM tmp_' || seq_id || ';'
ELSE ','
END AS values_list_estimate,

CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
'INSERT INTO ' || seq_id || '_moe (' ||
E'\n\tfileid, filetype, stusab, chariter, seq, logrecno,\n'
ELSE ''
END ||
E'\t' || cell_id || '_moe' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\n)'
ELSE ','
END AS insert_list_moe,

CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
E'SELECT fileid, filetype, upper(stusab), chariter, seq, logrecno::int,\n'
ELSE ''
END ||
E'\tNULLIF(NULLIF(' || cell_id || E'_moe, \'\'), \'.\')::double precision' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\nFROM tmp_' || seq_id || '_moe;'
ELSE ','
END AS values_list_moe/*,
CASE WHEN seq_position = min(seq_position) OVER (PARTITION BY seq) THEN
'INSERT INTO ' || seq_id ||
E'_moe\nSELECT fileid, filetype, upper(stusab), chariter, seq, logrecno::int,\n'
ELSE ''
END ||
E'\tNULLIF(NULLIF(' || cell_id || E'_moe, \'\'), \'.\')::double precision' ||
CASE WHEN seq_position = max(seq_position) OVER (PARTITION BY seq) THEN
E'\nFROM tmp_' || seq_id || '_moe;'
ELSE ','
END AS sql2*/
FROM
vw_cell
WHERE seq = ANY (seq_criteria2)
ORDER BY seq, seq_position
) step1
GROUP BY seq
) step2
;

--e means Estimates
Expand Down

0 comments on commit 4b4a0ed

Please sign in to comment.