Skip to content

Commit

Permalink
Snowfalke web: Update column check stored procedure (Close #125)
Browse files Browse the repository at this point in the history
  • Loading branch information
agnessnowplow committed Feb 18, 2022
1 parent 19ec98d commit 6482044
Showing 1 changed file with 61 additions and 7 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -89,12 +89,18 @@ CREATE OR REPLACE PROCEDURE {{.output_schema}}.column_check(SOURCE_SCHEMA VARCHA
var delim = '~';
var sourceColumns = list_cols_with_type(SOURCE_SCHEMA,SOURCE_TABLE,delim).split(delim);
var targetColumns = list_cols_with_type(TARGET_SCHEMA,TARGET_TABLE,delim).split(delim);
var sourceColumnLengths = list_cols_with_length(SOURCE_SCHEMA,SOURCE_TABLE,delim).split(delim);
var targetColumnLengths = list_cols_with_length(TARGET_SCHEMA,TARGET_TABLE,delim).split(delim);

if (targetColumns.some(notIncludedIn(sourceColumns)) === true) {

throw "ERROR: Source table is missing column(s) which exist in target table.";
if (targetColumns.length > sourceColumns.length) {
throw "ERROR: Source table is missing column(s) which exist in target table.";

} else {
for (var i = 0; i < targetColumns.length; i++) {
if (+targetColumnLengths[i] < +sourceColumnLengths[i]) {
throw "ERROR: varchar field in source column " + sourceColumns[i] + " is longer than varchar field in target column."
}
}

var columnAdditions = sourceColumns.filter(notIncludedIn(targetColumns));

Expand All @@ -105,11 +111,13 @@ CREATE OR REPLACE PROCEDURE {{.output_schema}}.column_check(SOURCE_SCHEMA VARCHA
// enforce order
for (var i = 0; i < targetColumns.length; i++) {
if (targetColumns[i] !== sourceColumns[i]) {
throw "ERROR: Can only migrate extra columns of the end of source"
throw "ERROR: Can only migrate extra columns of the end of source."
}
}
add_columns_to(TARGET_SCHEMA, TARGET_TABLE, columnAdditions.join(','));
return "ok.Columns added."
var pos = targetColumns.length + 1
var extraCols = list_extra_cols(SOURCE_SCHEMA,SOURCE_TABLE,delim, pos).split(delim);
add_columns_to(TARGET_SCHEMA, TARGET_TABLE, extraCols.join(','));
return "ok. Columns added."
}
} else {
return "ok. Columns match."
Expand All @@ -124,7 +132,7 @@ CREATE OR REPLACE PROCEDURE {{.output_schema}}.column_check(SOURCE_SCHEMA VARCHA
LISTAGG(
CASE
WHEN isc.data_type='TEXT'
THEN CONCAT(isc.column_name, ' VARCHAR(',isc.character_maximum_length, ')')
THEN isc.column_name
WHEN isc.data_type='NUMBER'
THEN CONCAT(isc.column_name, ' NUMBER(', isc.numeric_precision, ',',isc.numeric_scale, ')')
ELSE
Expand All @@ -142,6 +150,52 @@ CREATE OR REPLACE PROCEDURE {{.output_schema}}.column_check(SOURCE_SCHEMA VARCHA
return result;
}

function list_extra_cols(sch,tbl,delimiter,position) {
var stmt = `
SELECT
LISTAGG(
CASE
WHEN isc.data_type='TEXT'
THEN CONCAT(isc.column_name, ' VARCHAR(',isc.character_maximum_length, ')')
WHEN isc.data_type='NUMBER'
THEN CONCAT(isc.column_name, ' NUMBER(', isc.numeric_precision, ',',isc.numeric_scale, ')')
ELSE
CONCAT(isc.column_name, ' ', isc.data_type)
END, '` + delimiter + `')
WITHIN GROUP (order by isc.ordinal_position)
FROM information_schema.columns AS isc
WHERE table_schema='` + sch + `'
AND table_name='` + tbl + `'
AND isc.ordinal_position >='` + position + `';`;

var res = snowflake.createStatement({sqlText: stmt}).execute();
res.next();
result = res.getColumnValue(1);

return result;
}

function list_cols_with_length(sch,tbl,delimiter) {
var stmt = `
SELECT
LISTAGG(
CASE
WHEN isc.data_type='TEXT'
THEN isc.character_maximum_length
ELSE 0
END, '` + delimiter + `')
WITHIN GROUP (order by isc.ordinal_position)
FROM information_schema.columns AS isc
WHERE table_schema='` + sch + `'
AND table_name='` + tbl + `';`;

var res = snowflake.createStatement({sqlText: stmt}).execute();
res.next();
result = res.getColumnValue(1);

return result;
}

function notIncludedIn(arr) {
return function(elt) {
return ! arr.includes(elt);
Expand Down

0 comments on commit 6482044

Please sign in to comment.