Skip to content

Commit

Permalink
Fix inconsistent formatting issue in convert function when converting…
Browse files Browse the repository at this point in the history
… from money to varchar (#3337) (#3361)

Description
Currently when converting from money to varchar using convert function with different style values, the result is inconsistent with the formatting. This PR will address this issue by updating the logic to handle these edge cases. The issues that will get addressed in this PR are as follows

Extra space is getting added in the beginning of the result when style parameter is 0 or 2.
When input is 0, then 0 is missing before decimal in the result for style 0 and 2. Also for style 1 the result has $ before decimal instead of 0. For example, when converting value 0 with money datatype to varchar datatype
For style 0, result is  .00
For style 1, result is $.00
For style 2, result is  .0000
When style is 2, and the input has more than 2 digits after decimal, then the result is getting rounded upto 2 digits after decimal, which ideally should be rounded upto 4 digits.

Issues Resolved
BABEL-5462

Authored-by: Rohit Bhagat [email protected]
Signed-off-by: Rohit Bhagat [email protected]
  • Loading branch information
rohit01010 authored Jan 6, 2025
1 parent fbe64c3 commit 6cd7bc0
Show file tree
Hide file tree
Showing 41 changed files with 939 additions and 38 deletions.
32 changes: 13 additions & 19 deletions contrib/babelfishpg_tsql/sql/sys_function_helpers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9849,9 +9849,9 @@ BEGIN
END IF;
WHEN 'sys.money'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4)::pg_catalog.money);
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4));
ELSE
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4)::pg_catalog.money, p_style);
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4), p_style);
END IF;
ELSE
RETURN CAST(arg AS sys.VARCHAR);
Expand Down Expand Up @@ -9939,7 +9939,7 @@ LANGUAGE plpgsql
STABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_money_to_string(IN p_datatype TEXT,
IN p_moneyval PG_CATALOG.MONEY,
IN p_moneyval NUMERIC,
IN p_style NUMERIC DEFAULT 0)
RETURNS TEXT
AS
Expand All @@ -9953,8 +9953,6 @@ DECLARE
v_digits SMALLINT;
v_integral_digits SMALLINT;
v_decimal_digits SMALLINT;
v_res_length SMALLINT;
MASK_REGEXP CONSTANT VARCHAR COLLATE "C" := '^\s*(?:character varying)\s*\(\s*(\d+|MAX)\s*\)\s*$';
v_result TEXT;
BEGIN
v_style := floor(p_style)::SMALLINT;
Expand All @@ -9966,26 +9964,22 @@ BEGIN
v_integral_digits := v_digits;
END IF;
IF (v_style = 0) THEN
v_format := (pow(10, v_integral_digits)-1)::TEXT || 'D99';
v_result := to_char(v_moneyval, v_format);
v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D99';
v_result := pg_catalog.btrim(to_char(v_moneyval, v_format));
ELSIF (v_style = 1) THEN
IF (v_moneysign::SMALLINT = 1) THEN
v_result := substring(p_moneyval::TEXT, 2);
IF (v_moneysign::SMALLINT = -1) THEN
v_result := substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 1, 1) || substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 3);
ELSE
v_result := substring(p_moneyval::TEXT, 1, 1) || substring(p_moneyval::TEXT, 3);
v_result := substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 2);
END IF;
ELSIF (v_style = 2) THEN
v_format := (pow(10, v_integral_digits)-1)::TEXT || 'D9999';
v_result := to_char(v_moneyval, v_format);
ELSIF (v_style = 2 OR v_style = 126) THEN
v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D9999';
v_result := pg_catalog.btrim(to_char(v_moneyval, v_format));
ELSE
RAISE invalid_parameter_value;
END IF;
v_res_length := substring(p_datatype, MASK_REGEXP)::SMALLINT;
IF v_res_length IS NULL THEN
RETURN v_result;
ELSE
RETURN rpad(v_result, v_res_length, ' ');
END IF;

RETURN v_result;
EXCEPTION
WHEN invalid_parameter_value THEN
RAISE USING MESSAGE := pg_catalog.format('%s is not a valid style number when converting from MONEY to a character string.', v_style),
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10357,6 +10357,123 @@ END;
$$;
GRANT EXECUTE ON FUNCTION sys.columnproperty(object_id OID, property NAME, property_name TEXT) TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.babelfish_conv_to_varchar(IN typename TEXT,
IN arg anyelement,
IN p_style NUMERIC DEFAULT -1)
RETURNS sys.VARCHAR
AS
$BODY$
DECLARE
v_style SMALLINT;
BEGIN
v_style := floor(p_style)::SMALLINT;

CASE pg_typeof(arg)
WHEN 'date'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_date_to_string(typename, arg);
ELSE
RETURN sys.babelfish_try_conv_date_to_string(typename, arg, p_style);
END IF;
WHEN 'time'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_time_to_string(typename, 'TIME', arg);
ELSE
RETURN sys.babelfish_try_conv_time_to_string(typename, 'TIME', arg, p_style);
END IF;
WHEN 'sys.datetime'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_datetime_to_string(typename, 'DATETIME', arg::timestamp);
ELSE
RETURN sys.babelfish_try_conv_datetime_to_string(typename, 'DATETIME', arg::timestamp, p_style);
END IF;
WHEN 'float'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_float_to_string(typename, arg);
ELSE
RETURN sys.babelfish_try_conv_float_to_string(typename, arg, p_style);
END IF;
WHEN 'sys.money'::regtype THEN
IF v_style = -1 THEN
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4));
ELSE
RETURN sys.babelfish_try_conv_money_to_string(typename, arg::numeric(19,4), p_style);
END IF;
ELSE
RETURN CAST(arg AS sys.VARCHAR);
END CASE;
END;
$BODY$
LANGUAGE plpgsql
STABLE;

DO $$
DECLARE
exception_message text;
BEGIN
ALTER FUNCTION sys.babelfish_try_conv_money_to_string(TEXT, PG_CATALOG.MONEY, NUMERIC) RENAME TO babelfish_try_conv_money_to_string_deprecated_in_3_9_0;
EXCEPTION WHEN OTHERS THEN
GET STACKED DIAGNOSTICS
exception_message = MESSAGE_TEXT;
RAISE WARNING '%', exception_message;
END;
$$;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_money_to_string(IN p_datatype TEXT,
IN p_moneyval NUMERIC,
IN p_style NUMERIC DEFAULT 0)
RETURNS TEXT
AS
$BODY$
DECLARE
v_style SMALLINT;
v_format VARCHAR COLLATE "C";
v_moneyval NUMERIC(19,4) := p_moneyval::NUMERIC(19,4);
v_moneysign NUMERIC(19,4) := sign(v_moneyval);
v_moneyabs NUMERIC(19,4) := abs(v_moneyval);
v_digits SMALLINT;
v_integral_digits SMALLINT;
v_decimal_digits SMALLINT;
v_result TEXT;
BEGIN
v_style := floor(p_style)::SMALLINT;
v_digits := length(v_moneyabs::TEXT);
v_decimal_digits := scale(v_moneyabs);
IF (v_decimal_digits > 0) THEN
v_integral_digits := v_digits - v_decimal_digits - 1;
ELSE
v_integral_digits := v_digits;
END IF;
IF (v_style = 0) THEN
v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D99';
v_result := pg_catalog.btrim(to_char(v_moneyval, v_format));
ELSIF (v_style = 1) THEN
IF (v_moneysign::SMALLINT = -1) THEN
v_result := substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 1, 1) || substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 3);
ELSE
v_result := substring(p_moneyval::PG_CATALOG.MONEY::TEXT, 2);
END IF;
ELSIF (v_style = 2 OR v_style = 126) THEN
v_format := (pow(10, v_integral_digits)-10)::TEXT || 'D9999';
v_result := pg_catalog.btrim(to_char(v_moneyval, v_format));
ELSE
RAISE invalid_parameter_value;
END IF;

RETURN v_result;
EXCEPTION
WHEN invalid_parameter_value THEN
RAISE USING MESSAGE := pg_catalog.format('%s is not a valid style number when converting from MONEY to a character string.', v_style),
DETAIL := 'Use of incorrect "style" parameter value during conversion process.',
HINT := 'Change "style" parameter to the proper value and try again.';
END;
$BODY$
LANGUAGE plpgsql
STABLE
RETURNS NULL ON NULL INPUT;

CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'babelfish_try_conv_money_to_string_deprecated_in_3_9_0');

-- Drops the temporary procedure used by the upgrade script.
-- Please have this be one of the last statements executed in this upgrade script.
DROP PROCEDURE sys.babelfish_drop_deprecated_object(varchar, varchar, varchar);
Expand Down
8 changes: 4 additions & 4 deletions test/JDBC/expected/BABEL-1531.out
Original file line number Diff line number Diff line change
Expand Up @@ -2,21 +2,21 @@ SELECT CONVERT(varchar(50), CAST($23.12 AS money), 0);
GO
~~START~~
varchar
23.12
23.12
~~END~~

SELECT CONVERT(varchar(50), CAST($23.12 AS money), 2);
GO
~~START~~
varchar
23.1200
23.1200
~~END~~

SELECT CONVERT(varchar(50), CAST($23.12 as money));
GO
~~START~~
varchar
23.12
23.12
~~END~~

SELECT CONVERT(float, CAST($23.12 as money));
Expand Down Expand Up @@ -53,6 +53,6 @@ SELECT CONVERT(varchar(50), @mon);
GO
~~START~~
varchar
23.12
23.12
~~END~~

4 changes: 2 additions & 2 deletions test/JDBC/expected/BABEL-3486-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -1316,7 +1316,7 @@ SELECT * FROM BABEL_3486_vu_prepare_v54
GO
~~START~~
varchar
5.00
5.00
~~END~~

DROP VIEW BABEL_3486_vu_prepare_v54
Expand All @@ -1326,7 +1326,7 @@ EXEC BABEL_3486_vu_prepare_p54
GO
~~START~~
varchar
5.00
5.00
~~END~~

DROP PROCEDURE BABEL_3486_vu_prepare_p54
Expand Down
10 changes: 5 additions & 5 deletions test/JDBC/expected/babel_function.out
Original file line number Diff line number Diff line change
Expand Up @@ -188,21 +188,21 @@ select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 0);
GO
~~START~~
varchar
4936.56
4936.56
~~END~~

select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 1);
GO
~~START~~
varchar
4,936.56
4,936.56
~~END~~

select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 2);
GO
~~START~~
varchar
4936.5600
4936.5600
~~END~~


Expand All @@ -212,7 +212,7 @@ SELECT CONVERT(int, 99.9);
GO
~~START~~
varchar
-4936.56
-4936.56
~~END~~

~~START~~
Expand Down Expand Up @@ -311,7 +311,7 @@ select TRY_CONVERT(varchar(10), CAST(4936.56 AS MONEY), 0);
GO
~~START~~
varchar
4936.56
4936.56
~~END~~


Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -188,21 +188,21 @@ select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 0);
GO
~~START~~
varchar
4936.56
4936.56
~~END~~

select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 1);
GO
~~START~~
varchar
4,936.56
4,936.56
~~END~~

select CONVERT(varchar(10), CAST(4936.56 AS MONEY), 2);
GO
~~START~~
varchar
4936.5600
4936.5600
~~END~~


Expand All @@ -212,7 +212,7 @@ SELECT CONVERT(int, 99.9);
GO
~~START~~
varchar
-4936.56
-4936.56
~~END~~

~~START~~
Expand Down Expand Up @@ -311,7 +311,7 @@ select TRY_CONVERT(varchar(10), CAST(4936.56 AS MONEY), 0);
GO
~~START~~
varchar
4936.56
4936.56
~~END~~


Expand Down
11 changes: 11 additions & 0 deletions test/JDBC/expected/test_conv_money_to_varchar-vu-cleanup.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
DROP VIEW test_conv_string_to_date_v1
GO

DROP PROCEDURE test_conv_string_to_date_p1
GO

DROP FUNCTION test_conv_string_to_date_f1
GO

DROP TABLE test_conv_money_to_varchar_t1
GO
39 changes: 39 additions & 0 deletions test/JDBC/expected/test_conv_money_to_varchar-vu-prepare.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
CREATE TABLE test_conv_money_to_varchar_t1(val money)
GO

INSERT INTO test_conv_money_to_varchar_t1 VALUES (1234), (0), (123.12), (0.12456)
GO
~~ROW COUNT: 4~~


CREATE VIEW test_conv_string_to_date_v1 as (
SELECT val,
val_convert = '$' + CONVERT(VARCHAR, val) ,
val_convert_style_0 = '$' + CONVERT(VARCHAR, val, 0),
val_convert_style_1 = '$' + CONVERT(VARCHAR, val, 1),
val_convert_style_2 = '$' + CONVERT(VARCHAR, val, 2)
FROM test_conv_money_to_varchar_t1
);
GO

CREATE PROCEDURE test_conv_string_to_date_p1 as (
SELECT val,
val_convert = '$' + CONVERT(VARCHAR, val) ,
val_convert_style_0 = '$' + CONVERT(VARCHAR, val, 0),
val_convert_style_1 = '$' + CONVERT(VARCHAR, val, 1),
val_convert_style_2 = '$' + CONVERT(VARCHAR, val, 2)
FROM test_conv_money_to_varchar_t1
);
GO

CREATE FUNCTION test_conv_string_to_date_f1()
RETURNS TABLE AS
RETURN (
SELECT val,
val_convert = '$' + CONVERT(VARCHAR, val) ,
val_convert_style_0 = '$' + CONVERT(VARCHAR, val, 0),
val_convert_style_1 = '$' + CONVERT(VARCHAR, val, 1),
val_convert_style_2 = '$' + CONVERT(VARCHAR, val, 2)
FROM test_conv_money_to_varchar_t1
);
GO
Loading

0 comments on commit 6cd7bc0

Please sign in to comment.