Skip to content

Commit

Permalink
Support user defined data-types for COL_LENGTH() function (babelfish-…
Browse files Browse the repository at this point in the history
…for-postgresql#1906)

* Support user defined data-types for COL_LENGTH() function

Before this, whenever a custom type was created and passed to the
COL_LENGTH(), it threw NULL. This change fixes this and support user
defined data types.


Task: BABEL-3489

Signed-off-by: Roshan Kanwar <[email protected]>
  • Loading branch information
roshan0708 authored and ahmed-shameem committed Oct 25, 2023
1 parent 3091f1a commit 843132c
Show file tree
Hide file tree
Showing 8 changed files with 833 additions and 215 deletions.
130 changes: 49 additions & 81 deletions contrib/babelfishpg_tsql/sql/sys_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4014,93 +4014,61 @@ GRANT EXECUTE ON FUNCTION sys.fn_listextendedproperty TO PUBLIC;
-- Matches and returns column length of the corresponding column of the given table
CREATE OR REPLACE FUNCTION sys.COL_LENGTH(IN object_name TEXT, IN column_name TEXT)
RETURNS SMALLINT AS $BODY$
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length INT;
column_data_type TEXT;
column_precision INT;
BEGIN
-- Get the object ID for the provided object_name
object_id = sys.OBJECT_ID(object_name);
IF object_id IS NULL THEN
RETURN NULL;
END IF;
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length SMALLINT;
column_data_type TEXT;
typeid oid;
typelen INT;
typemod INT;
BEGIN
-- Get the object ID for the provided object_name
object_id := sys.OBJECT_ID(object_name, 'U');
IF object_id IS NULL THEN
RETURN NULL;
END IF;

-- Truncate and normalize the column name
col_name = sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));
-- Truncate and normalize the column name
col_name := sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));

-- Get the column ID for the provided column_name
SELECT attnum INTO column_id FROM pg_attribute
WHERE attrelid = object_id AND lower(attname) = col_name
COLLATE sys.database_default;
-- Get the column ID, typeid, length, and typmod for the provided column_name
SELECT attnum, a.atttypid, a.attlen, a.atttypmod
INTO column_id, typeid, typelen, typemod
FROM pg_attribute a
WHERE attrelid = object_id AND lower(attname) = col_name COLLATE sys.database_default;

IF column_id IS NULL THEN
RETURN NULL;
END IF;
IF column_id IS NULL THEN
RETURN NULL;
END IF;

-- Get the correct data type
column_data_type := sys.translate_pg_type_to_tsql(typeid);

IF column_data_type = 'sysname' THEN
column_length := 256;
ELSIF column_data_type IS NULL THEN

-- Check if it's a user-defined data type
SELECT sys.translate_pg_type_to_tsql(typbasetype), typlen, typtypmod
INTO column_data_type, typelen, typemod
FROM pg_type
WHERE oid = typeid;

-- Retrieve the data type, precision, scale, and column length in characters
SELECT a.atttypid::regtype,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) >> 16) & 65535
ELSE NULL
END,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) & 65535)
ELSE a.atttypmod
END
INTO column_data_type, column_precision, column_length
FROM pg_attribute a
WHERE a.attrelid = object_id AND a.attnum = column_id;

-- Remove delimiters
column_data_type := sys.babelfish_remove_delimiter_pair(column_data_type);

IF column_data_type IS NOT NULL THEN
column_length := CASE
-- Columns declared with max specifier case
WHEN column_length = -1 AND column_data_type IN ('varchar', 'nvarchar', 'varbinary')
THEN -1
WHEN column_data_type = 'xml'
THEN -1
WHEN column_data_type IN ('tinyint', 'bit')
THEN 1
WHEN column_data_type = 'smallint'
THEN 2
WHEN column_data_type = 'date'
THEN 3
WHEN column_data_type IN ('int', 'integer', 'real', 'smalldatetime', 'smallmoney')
THEN 4
WHEN column_data_type IN ('time', 'time without time zone')
THEN 5
WHEN column_data_type IN ('double precision', 'bigint', 'datetime', 'datetime2', 'money')
THEN 8
WHEN column_data_type = 'datetimeoffset'
THEN 10
WHEN column_data_type IN ('uniqueidentifier', 'text', 'image', 'ntext')
THEN 16
WHEN column_data_type = 'sysname'
THEN 256
WHEN column_data_type = 'sql_variant'
THEN 8016
WHEN column_data_type IN ('bpchar', 'char', 'varchar', 'binary', 'varbinary')
THEN column_length
WHEN column_data_type IN ('nchar', 'nvarchar')
THEN column_length * 2
WHEN column_data_type IN ('numeric', 'decimal')
THEN
CASE
WHEN column_precision IS NULL
THEN NULL
ELSE ((column_precision + 8) / 9 * 4 + 1)
END
ELSE NULL
END;
IF column_data_type = 'sysname' THEN
column_length := 256;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;

RETURN column_length::SMALLINT;
END;
RETURN column_length;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -437,93 +437,61 @@ LANGUAGE plpgsql;
-- Matches and returns column length of the corresponding column of the given table
CREATE OR REPLACE FUNCTION sys.COL_LENGTH(IN object_name TEXT, IN column_name TEXT)
RETURNS SMALLINT AS $BODY$
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length INT;
column_data_type TEXT;
column_precision INT;
BEGIN
-- Get the object ID for the provided object_name
object_id = sys.OBJECT_ID(object_name);
IF object_id IS NULL THEN
RETURN NULL;
END IF;
DECLARE
col_name TEXT;
object_id oid;
column_id INT;
column_length SMALLINT;
column_data_type TEXT;
typeid oid;
typelen INT;
typemod INT;
BEGIN
-- Get the object ID for the provided object_name
object_id := sys.OBJECT_ID(object_name, 'U');
IF object_id IS NULL THEN
RETURN NULL;
END IF;

-- Truncate and normalize the column name
col_name = sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));
-- Truncate and normalize the column name
col_name := sys.babelfish_truncate_identifier(sys.babelfish_remove_delimiter_pair(lower(column_name)));

-- Get the column ID for the provided column_name
SELECT attnum INTO column_id FROM pg_attribute
WHERE attrelid = object_id AND lower(attname) = col_name
COLLATE sys.database_default;
-- Get the column ID, typeid, length, and typmod for the provided column_name
SELECT attnum, a.atttypid, a.attlen, a.atttypmod
INTO column_id, typeid, typelen, typemod
FROM pg_attribute a
WHERE attrelid = object_id AND lower(attname) = col_name COLLATE sys.database_default;

IF column_id IS NULL THEN
RETURN NULL;
END IF;
IF column_id IS NULL THEN
RETURN NULL;
END IF;

-- Get the correct data type
column_data_type := sys.translate_pg_type_to_tsql(typeid);

IF column_data_type = 'sysname' THEN
column_length := 256;
ELSIF column_data_type IS NULL THEN

-- Check if it's a user-defined data type
SELECT sys.translate_pg_type_to_tsql(typbasetype), typlen, typtypmod
INTO column_data_type, typelen, typemod
FROM pg_type
WHERE oid = typeid;

-- Retrieve the data type, precision, scale, and column length in characters
SELECT a.atttypid::regtype,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) >> 16) & 65535
ELSE NULL
END,
CASE
WHEN a.atttypmod > 0 THEN ((a.atttypmod - 4) & 65535)
ELSE a.atttypmod
END
INTO column_data_type, column_precision, column_length
FROM pg_attribute a
WHERE a.attrelid = object_id AND a.attnum = column_id;

-- Remove delimiters
column_data_type := sys.babelfish_remove_delimiter_pair(column_data_type);

IF column_data_type IS NOT NULL THEN
column_length := CASE
-- Columns declared with max specifier case
WHEN column_length = -1 AND column_data_type IN ('varchar', 'nvarchar', 'varbinary')
THEN -1
WHEN column_data_type = 'xml'
THEN -1
WHEN column_data_type IN ('tinyint', 'bit')
THEN 1
WHEN column_data_type = 'smallint'
THEN 2
WHEN column_data_type = 'date'
THEN 3
WHEN column_data_type IN ('int', 'integer', 'real', 'smalldatetime', 'smallmoney')
THEN 4
WHEN column_data_type IN ('time', 'time without time zone')
THEN 5
WHEN column_data_type IN ('double precision', 'bigint', 'datetime', 'datetime2', 'money')
THEN 8
WHEN column_data_type = 'datetimeoffset'
THEN 10
WHEN column_data_type IN ('uniqueidentifier', 'text', 'image', 'ntext')
THEN 16
WHEN column_data_type = 'sysname'
THEN 256
WHEN column_data_type = 'sql_variant'
THEN 8016
WHEN column_data_type IN ('bpchar', 'char', 'varchar', 'binary', 'varbinary')
THEN column_length
WHEN column_data_type IN ('nchar', 'nvarchar')
THEN column_length * 2
WHEN column_data_type IN ('numeric', 'decimal')
THEN
CASE
WHEN column_precision IS NULL
THEN NULL
ELSE ((column_precision + 8) / 9 * 4 + 1)
END
ELSE NULL
END;
IF column_data_type = 'sysname' THEN
column_length := 256;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;
ELSE
-- Calculate column length based on base type information
column_length := sys.tsql_type_max_length_helper(column_data_type, typelen, typemod);
END IF;

RETURN column_length::SMALLINT;
END;
RETURN column_length;
END;
$BODY$
LANGUAGE plpgsql
IMMUTABLE
Expand Down
35 changes: 35 additions & 0 deletions test/JDBC/expected/col_length-vu-cleanup.out
Original file line number Diff line number Diff line change
Expand Up @@ -60,3 +60,38 @@ DROP FUNCTION IF EXISTS col_length_prepare_f14();
DROP FUNCTION IF EXISTS col_length_prepare_f15();
DROP FUNCTION IF EXISTS col_length_prepare_f16();
GO

-- Drop types
DROP TYPE IF EXISTS custom_char_10;
DROP TYPE IF EXISTS custom_varchar_20;
DROP TYPE IF EXISTS custom_binary_5;
DROP TYPE IF EXISTS custom_varbinary_15;
DROP TYPE IF EXISTS custom_nchar_8;
DROP TYPE IF EXISTS custom_nvarchar_16;
DROP TYPE IF EXISTS custom_text;
DROP TYPE IF EXISTS custom_image;
DROP TYPE IF EXISTS custom_ntext;
DROP TYPE IF EXISTS custom_sysname;
DROP TYPE IF EXISTS custom_sql_variant;
DROP TYPE IF EXISTS custom_xml;
DROP TYPE IF EXISTS custom_varcharmax;
DROP TYPE IF EXISTS custom_nvarcharmax;
DROP TYPE IF EXISTS custom_varbinarymax;
DROP TYPE IF EXISTS custom_bit;
DROP TYPE IF EXISTS custom_tinyint;
DROP TYPE IF EXISTS custom_bigint;
DROP TYPE IF EXISTS custom_smallint;
DROP TYPE IF EXISTS custom_smallmoney;
DROP TYPE IF EXISTS custom_money;
DROP TYPE IF EXISTS custom_smalldatetime;
DROP TYPE IF EXISTS custom_real;
DROP TYPE IF EXISTS custom_float;
DROP TYPE IF EXISTS custom_time;
DROP TYPE IF EXISTS custom_datetime;
DROP TYPE IF EXISTS custom_datetime2;
DROP TYPE IF EXISTS custom_datetimeoffset;
DROP TYPE IF EXISTS custom_uniqueidentifier;
DROP TYPE IF EXISTS custom_date;
DROP TYPE IF EXISTS custom_decimal_10_5;
DROP TYPE IF EXISTS custom_numeric_3_0;
GO
Loading

0 comments on commit 843132c

Please sign in to comment.