Skip to content

Commit

Permalink
db: fix fn_db_change_column_null
Browse files Browse the repository at this point in the history
Changing the function that sets a column in the part that turns from
NULL to not NULL to set any found NULL values on the changed column
values to a default value according to the column type.

This script changes also upgrade scripts to pass the v_type new
parameter.

In case that unsupported type is passed, an error is thrown.

This patch also removed redundant code added in PRs 297 and 300

Signed-off-by: Eli Mesika <emesika@redhat.com>
Bug-Url: https://bugzilla.redhat.com/2077387
Allow-db-upgrade-script-changes: Yes
  • Loading branch information
emesika committed May 24, 2022
1 parent 9979165 commit e307d60
Show file tree
Hide file tree
Showing 3 changed files with 31 additions and 24 deletions.
30 changes: 28 additions & 2 deletions packaging/dbscripts/common_sp.sql
Original file line number Diff line number Diff line change
Expand Up @@ -55,18 +55,44 @@ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION fn_db_change_column_null (
v_table VARCHAR(128),
v_column VARCHAR(128),
v_allow_null BOOLEAN
v_allow_null BOOLEAN,
v_type varchar
)
RETURNS void AS $PROCEDURE$
DECLARE v_sql TEXT;

BEGIN
IF (v_allow_null) THEN
v_sql := 'ALTER TABLE ' || v_table || ' ALTER COLUMN ' || v_column || ' DROP NOT NULL';
EXECUTE v_sql;
ELSE
-- Get the column type
IF v_type = 'bool' THEN
v_sql := ' = false';
ELSIF v_type = 'char' THEN
v_sql := ' = '''' ';
ELSIF v_type = 'varchar' THEN
v_sql := ' = '''' ';
ELSIF v_type = 'text' THEN
v_sql := ' = '''' ';
ELSIF v_type = 'int' THEN
v_sql := ' = 0 ';
ELSIF v_type = 'float' THEN
v_sql := ' = 0.0 ';
ELSIF v_type = 'numeric' THEN
v_sql := ' = 0 ';
ELSIF v_type = 'uuid' THEN
v_sql := ' = ''00000000-0000-0000-0000-000000000000'' ';
ELSE
RAISE EXCEPTION 'fn_db_change_column_null(%,%,%,%) unrecognized type', v_table, v_column, v_allow_null, v_type;
END IF;
-- Insure that there are no NULL values in the table column before setting it to NOT NULL
v_sql := 'update ' || v_table || ' set ' || v_column || v_sql || ' where ' || v_column || ' IS NULL';
EXECUTE v_sql;
v_sql := 'ALTER TABLE ' || v_table || ' ALTER COLUMN ' || v_column || ' SET NOT NULL';
EXECUTE v_sql;

END IF;
EXECUTE v_sql;

END;$PROCEDURE$
LANGUAGE plpgsql;
Expand Down
Original file line number Diff line number Diff line change
@@ -1,21 +1,2 @@
-- Make sure that forgotten options from ancient releases have default value
UPDATE vdc_options
SET default_value = option_value
WHERE
default_value IS NULL
AND option_value IS NOT NULL;

-- If there are still some crappy options, let's set default value to empty string
UPDATE vdc_options
SET default_value = ''
WHERE
default_value IS NULL
AND option_value IS NULL;

-- We shouldn't have any options with NULL values by now, but let's make sure
UPDATE vdc_options
SET option_value = ''
WHERE option_value IS NULL;

SELECT fn_db_change_column_null('vdc_options', 'default_value', false);
SELECT fn_db_change_column_null('vdc_options', 'option_value', false);
SELECT fn_db_change_column_null('vdc_options', 'default_value', false, 'text');
SELECT fn_db_change_column_null('vdc_options', 'option_value', false, 'text');
2 changes: 1 addition & 1 deletion packaging/dbscripts/upgrade/pre_upgrade/0000_config.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1456,4 +1456,4 @@ select fn_db_split_config_value('LiveSnapshotPerformFreezeInEngine', 'false', 'f
--
-- This must be the last section of the file!
------------------------------------------------------------------------------------
select fn_db_change_column_null('vdc_options', 'default_value', false);
select fn_db_change_column_null('vdc_options', 'default_value', false, 'text');

0 comments on commit e307d60

Please sign in to comment.