Skip to content

Commit

Permalink
Fixed CONVERT function behavior for BINARY and VARBINARY types (#3052)
Browse files Browse the repository at this point in the history
This change addresses inconsistencies in the CONVERT function's behavior when used with BINARY and VARBINARY types in Babelfish. Previously, Babelfish was not correctly handling style arguments and hexadecimal input for these conversions. With this change, the behavior now more closely aligns with SQL Server's implementation.

For CONVERT(BINARY(n), '0x...', 1), the function now correctly interprets the input string as hexadecimal values instead of ASCII characters, adhering to the specified style.

When NULL is provided as the style argument, the function now correctly returns NULL for both BINARY and VARBINARY types.

For both BINARY and VARBINARY conversions, the function now properly considers the style argument, ensuring consistent behavior across different styles.

Fixed an issue where style 2 was not being handled correctly, leading to unexpected results.

Issues Resolved
Task: BABEL-2736
  • Loading branch information
R4hul04 authored Oct 25, 2024
1 parent 75b7f2a commit a3dc2ad
Show file tree
Hide file tree
Showing 32 changed files with 9,001 additions and 2 deletions.
106 changes: 106 additions & 0 deletions contrib/babelfishpg_tsql/sql/sys_function_helpers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9655,6 +9655,112 @@ $BODY$
LANGUAGE plpgsql
STABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_conv_helper_to_varbinary(IN arg anyelement,
IN try BOOL,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF try THEN
RETURN sys.babelfish_try_conv_to_varbinary(arg, p_style);
ELSE
IF pg_typeof(arg) IN ('text'::regtype, 'sys.ntext'::regtype, 'sys.nvarchar'::regtype, 'sys.bpchar'::regtype, 'sys.nchar'::regtype) THEN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN CAST(arg AS sys.varbinary);
END IF;
END IF;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_conv_helper_to_varbinary(IN arg sys.VARCHAR,
IN try BOOL,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF try THEN
RETURN sys.babelfish_try_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
END IF;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_string_to_varbinary(IN arg sys.VARCHAR,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
EXCEPTION
WHEN OTHERS THEN
RETURN NULL;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_to_varbinary(IN arg anyelement,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF pg_typeof(arg) IN ('text'::regtype, 'sys.ntext'::regtype, 'sys.nvarchar'::regtype, 'sys.bpchar'::regtype, 'sys.nchar'::regtype) THEN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN CAST(arg AS sys.varbinary);
END IF;
EXCEPTION
WHEN OTHERS THEN
RETURN NULL;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

-- Helper function to convert to binary or varbinary
CREATE OR REPLACE FUNCTION sys.babelfish_conv_string_to_varbinary(IN input_value sys.VARCHAR, IN style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
DECLARE
result bytea;
BEGIN
IF style = 0 THEN
RETURN CAST(input_value AS sys.varbinary);
ELSIF style = 1 THEN
-- Handle hexadecimal conversion
IF (PG_CATALOG.left(input_value, 2) = '0x' COLLATE "C" AND PG_CATALOG.length(input_value) % 2 = 0) THEN
result := decode(substring(input_value from 3), 'hex');
ELSE
RAISE EXCEPTION 'Error converting data type varchar to varbinary.';
END IF;
ELSIF style = 2 THEN
IF PG_CATALOG.left(input_value, 2) = '0x' COLLATE "C" THEN
RAISE EXCEPTION 'Error converting data type varchar to varbinary.';
ELSE
result := decode(input_value, 'hex');
END IF;
ELSE
RAISE EXCEPTION 'The style % is not supported for conversions from varchar to varbinary.', style;
END IF;

RETURN CAST(result AS sys.varbinary);
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE
STRICT;

-- convertion to varchar
CREATE OR REPLACE FUNCTION sys.babelfish_conv_helper_to_varchar(IN typename TEXT,
IN arg TEXT,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -9303,6 +9303,112 @@ end;
$body$
language plpgsql immutable returns null on null input;

CREATE OR REPLACE FUNCTION sys.babelfish_conv_helper_to_varbinary(IN arg anyelement,
IN try BOOL,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF try THEN
RETURN sys.babelfish_try_conv_to_varbinary(arg, p_style);
ELSE
IF pg_typeof(arg) IN ('text'::regtype, 'sys.ntext'::regtype, 'sys.nvarchar'::regtype, 'sys.bpchar'::regtype, 'sys.nchar'::regtype) THEN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN CAST(arg AS sys.varbinary);
END IF;
END IF;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_conv_helper_to_varbinary(IN arg sys.VARCHAR,
IN try BOOL,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF try THEN
RETURN sys.babelfish_try_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
END IF;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_string_to_varbinary(IN arg sys.VARCHAR,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
EXCEPTION
WHEN OTHERS THEN
RETURN NULL;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

CREATE OR REPLACE FUNCTION sys.babelfish_try_conv_to_varbinary(IN arg anyelement,
IN p_style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
BEGIN
IF pg_typeof(arg) IN ('text'::regtype, 'sys.ntext'::regtype, 'sys.nvarchar'::regtype, 'sys.bpchar'::regtype, 'sys.nchar'::regtype) THEN
RETURN sys.babelfish_conv_string_to_varbinary(arg, p_style);
ELSE
RETURN CAST(arg AS sys.varbinary);
END IF;
EXCEPTION
WHEN OTHERS THEN
RETURN NULL;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE;

-- Helper function to convert to binary or varbinary
CREATE OR REPLACE FUNCTION sys.babelfish_conv_string_to_varbinary(IN input_value sys.VARCHAR, IN style NUMERIC DEFAULT 0)
RETURNS sys.varbinary
AS
$BODY$
DECLARE
result bytea;
BEGIN
IF style = 0 THEN
RETURN CAST(input_value AS sys.varbinary);
ELSIF style = 1 THEN
-- Handle hexadecimal conversion
IF (PG_CATALOG.left(input_value, 2) = '0x' COLLATE "C" AND PG_CATALOG.length(input_value) % 2 = 0) THEN
result := decode(substring(input_value from 3), 'hex');
ELSE
RAISE EXCEPTION 'Error converting data type varchar to varbinary.';
END IF;
ELSIF style = 2 THEN
IF PG_CATALOG.left(input_value, 2) = '0x' COLLATE "C" THEN
RAISE EXCEPTION 'Error converting data type varchar to varbinary.';
ELSE
result := decode(input_value, 'hex');
END IF;
ELSE
RAISE EXCEPTION 'The style % is not supported for conversions from varchar to varbinary.', style;
END IF;

RETURN CAST(result AS sys.varbinary);
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE
STRICT;

-- This is a temporary procedure which is called during upgrade to alter
-- default privileges on all the schemas where the schema owner is not dbo/db_owner
CREATE OR REPLACE PROCEDURE sys.babelfish_alter_default_privilege_on_schema()
Expand Down
10 changes: 10 additions & 0 deletions contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-epilogue.y.c
Original file line number Diff line number Diff line change
Expand Up @@ -216,6 +216,16 @@ TsqlFunctionConvert(TypeName *typename, Node *arg, Node *style, bool try, int lo
*/
result = makeTypeCast(helperFuncCall, typename, location);
}

else if (strcmp(typename_string, "binary") == 0 || strcmp(typename_string, "varbinary") == 0)
{
Node *helperFuncCall;
helperFuncCall = (Node *) makeFuncCall(TsqlSystemFuncName("babelfish_conv_helper_to_varbinary"), args, COERCE_EXPLICIT_CALL, location);

// add a type cast on top of the CONVERT helper function so typmod can be applied
result = makeTypeCast(helperFuncCall, typename, location);
}

else
{
if (try)
Expand Down
Loading

0 comments on commit a3dc2ad

Please sign in to comment.