Skip to content

Commit

Permalink
DMS - Allow TSQL System views to display BYTEA datatype information (b…
Browse files Browse the repository at this point in the history
…abelfish-for-postgresql#1532)

This change allows Information_schema_tsql to return PG base types and sp_columns_100 to return data for bytea columns as well.

Signed-off-by: Sai Rohan Basa [email protected]
  • Loading branch information
basasairohan committed Jun 1, 2023
1 parent be4c1ba commit f3730eb
Show file tree
Hide file tree
Showing 27 changed files with 344 additions and 16 deletions.
2 changes: 1 addition & 1 deletion contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -376,7 +376,7 @@ CREATE OR REPLACE VIEW sys.sp_columns_100_view AS
)
, sys.translate_pg_type_to_tsql(a.atttypid) AS tsql_type_name
, sys.spt_datatype_info_table AS t5
WHERE (t4."DATA_TYPE" = CAST(t5.TYPE_NAME AS sys.nvarchar(128)))
WHERE (t4."DATA_TYPE" = CAST(t5.TYPE_NAME AS sys.nvarchar(128)) OR (t4."DATA_TYPE" = 'bytea' AND t5.TYPE_NAME = 'image'))
AND ext.dbid = cast(sys.db_id() as oid);

GRANT SELECT on sys.sp_columns_100_view TO PUBLIC;
Expand Down
1 change: 1 addition & 0 deletions contrib/babelfishpg_tsql/sql/information_schema_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -250,6 +250,7 @@ CREATE OR REPLACE VIEW information_schema_tsql.columns AS

CAST(
CASE WHEN tsql_type_name = 'sysname' THEN sys.translate_pg_type_to_tsql(t.typbasetype)
WHEN tsql_type_name.tsql_type_name IS NULL THEN format_type(t.oid, NULL::integer)
ELSE tsql_type_name END
AS sys.nvarchar(128))
AS "DATA_TYPE",
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -127,6 +127,185 @@ SELECT
FROM sys.babelfish_syslanguages;
GRANT SELECT ON sys.syslanguages TO PUBLIC;

CREATE OR REPLACE VIEW sys.sp_columns_100_view AS
SELECT
CAST(t4."TABLE_CATALOG" AS sys.sysname) AS TABLE_QUALIFIER,
CAST(t4."TABLE_SCHEMA" AS sys.sysname) AS TABLE_OWNER,
CAST(t4."TABLE_NAME" AS sys.sysname) AS TABLE_NAME,
CAST(t4."COLUMN_NAME" AS sys.sysname) AS COLUMN_NAME,
CAST(t5.data_type AS smallint) AS DATA_TYPE,
CAST(coalesce(tsql_type_name, t.typname) AS sys.sysname) AS TYPE_NAME,

CASE WHEN t4."CHARACTER_MAXIMUM_LENGTH" = -1 THEN 0::INT
WHEN a.atttypmod != -1
THEN
CAST(coalesce(t4."NUMERIC_PRECISION", t4."CHARACTER_MAXIMUM_LENGTH", sys.tsql_type_precision_helper(t4."DATA_TYPE", a.atttypmod)) AS INT)
WHEN tsql_type_name = 'timestamp'
THEN 8
ELSE
CAST(coalesce(t4."NUMERIC_PRECISION", t4."CHARACTER_MAXIMUM_LENGTH", sys.tsql_type_precision_helper(t4."DATA_TYPE", t.typtypmod)) AS INT)
END AS PRECISION,

CASE WHEN a.atttypmod != -1
THEN
CAST(sys.tsql_type_length_for_sp_columns_helper(t4."DATA_TYPE", a.attlen, a.atttypmod) AS int)
ELSE
CAST(sys.tsql_type_length_for_sp_columns_helper(t4."DATA_TYPE", a.attlen, t.typtypmod) AS int)
END AS LENGTH,


CASE WHEN a.atttypmod != -1
THEN
CAST(coalesce(t4."NUMERIC_SCALE", sys.tsql_type_scale_helper(t4."DATA_TYPE", a.atttypmod, true)) AS smallint)
ELSE
CAST(coalesce(t4."NUMERIC_SCALE", sys.tsql_type_scale_helper(t4."DATA_TYPE", t.typtypmod, true)) AS smallint)
END AS SCALE,


CAST(coalesce(t4."NUMERIC_PRECISION_RADIX", sys.tsql_type_radix_for_sp_columns_helper(t4."DATA_TYPE")) AS smallint) AS RADIX,
case
when t4."IS_NULLABLE" = 'YES' then CAST(1 AS smallint)
else CAST(0 AS smallint)
end AS NULLABLE,

CAST(NULL AS varchar(254)) AS remarks,
CAST(t4."COLUMN_DEFAULT" AS sys.nvarchar(4000)) AS COLUMN_DEF,
CAST(t5.sql_data_type AS smallint) AS SQL_DATA_TYPE,
CAST(t5.SQL_DATETIME_SUB AS smallint) AS SQL_DATETIME_SUB,

CASE WHEN t4."DATA_TYPE" = 'xml' THEN 0::INT
WHEN t4."DATA_TYPE" = 'sql_variant' THEN 8000::INT
WHEN t4."CHARACTER_MAXIMUM_LENGTH" = -1 THEN 0::INT
ELSE CAST(t4."CHARACTER_OCTET_LENGTH" AS int)
END AS CHAR_OCTET_LENGTH,

CAST(t4."ORDINAL_POSITION" AS int) AS ORDINAL_POSITION,
CAST(t4."IS_NULLABLE" AS varchar(254)) AS IS_NULLABLE,
CAST(t5.ss_data_type AS sys.tinyint) AS SS_DATA_TYPE,
CAST(0 AS smallint) AS SS_IS_SPARSE,
CAST(0 AS smallint) AS SS_IS_COLUMN_SET,
CAST(t6.is_computed as smallint) AS SS_IS_COMPUTED,
CAST(t6.is_identity as smallint) AS SS_IS_IDENTITY,
CAST(NULL AS varchar(254)) SS_UDT_CATALOG_NAME,
CAST(NULL AS varchar(254)) SS_UDT_SCHEMA_NAME,
CAST(NULL AS varchar(254)) SS_UDT_ASSEMBLY_TYPE_NAME,
CAST(NULL AS varchar(254)) SS_XML_SCHEMACOLLECTION_CATALOG_NAME,
CAST(NULL AS varchar(254)) SS_XML_SCHEMACOLLECTION_SCHEMA_NAME,
CAST(NULL AS varchar(254)) SS_XML_SCHEMACOLLECTION_NAME

FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN pg_catalog.pg_roles t3 ON t1.relowner = t3.oid
LEFT OUTER JOIN sys.babelfish_namespace_ext ext on t2.nspname = ext.nspname
JOIN information_schema_tsql.columns t4 ON (t1.relname::sys.nvarchar(128) = t4."TABLE_NAME" AND ext.orig_name = t4."TABLE_SCHEMA")
LEFT JOIN pg_attribute a on a.attrelid = t1.oid AND a.attname::sys.nvarchar(128) = t4."COLUMN_NAME"
LEFT JOIN pg_type t ON t.oid = a.atttypid
LEFT JOIN sys.columns t6 ON
(
t1.oid = t6.object_id AND
t4."ORDINAL_POSITION" = t6.column_id
)
, sys.translate_pg_type_to_tsql(a.atttypid) AS tsql_type_name
, sys.spt_datatype_info_table AS t5
WHERE (t4."DATA_TYPE" = CAST(t5.TYPE_NAME AS sys.nvarchar(128)) OR (t4."DATA_TYPE" = 'bytea' AND t5.TYPE_NAME = 'image'))
AND ext.dbid = cast(sys.db_id() as oid);

GRANT SELECT on sys.sp_columns_100_view TO PUBLIC;

CREATE OR REPLACE VIEW information_schema_tsql.columns AS
SELECT CAST(nc.dbname AS sys.nvarchar(128)) AS "TABLE_CATALOG",
CAST(ext.orig_name AS sys.nvarchar(128)) AS "TABLE_SCHEMA",
CAST(c.relname AS sys.nvarchar(128)) AS "TABLE_NAME",
CAST(a.attname AS sys.nvarchar(128)) AS "COLUMN_NAME",
CAST(a.attnum AS int) AS "ORDINAL_POSITION",
CAST(CASE WHEN a.attgenerated = '' THEN pg_get_expr(ad.adbin, ad.adrelid) END AS sys.nvarchar(4000)) AS "COLUMN_DEFAULT",
CAST(CASE WHEN a.attnotnull OR (t.typtype = 'd' AND t.typnotnull) THEN 'NO' ELSE 'YES' END
AS varchar(3))
AS "IS_NULLABLE",

CAST(
CASE WHEN tsql_type_name = 'sysname' THEN sys.translate_pg_type_to_tsql(t.typbasetype)
WHEN tsql_type_name.tsql_type_name IS NULL THEN format_type(t.oid, NULL::integer)
ELSE tsql_type_name END
AS sys.nvarchar(128))
AS "DATA_TYPE",

CAST(
information_schema_tsql._pgtsql_char_max_length(tsql_type_name, true_typmod)
AS int)
AS "CHARACTER_MAXIMUM_LENGTH",

CAST(
information_schema_tsql._pgtsql_char_octet_length(tsql_type_name, true_typmod)
AS int)
AS "CHARACTER_OCTET_LENGTH",

CAST(
/* Handle Tinyint separately */
information_schema_tsql._pgtsql_numeric_precision(tsql_type_name, true_typid, true_typmod)
AS sys.tinyint)
AS "NUMERIC_PRECISION",

CAST(
information_schema_tsql._pgtsql_numeric_precision_radix(tsql_type_name, true_typid, true_typmod)
AS smallint)
AS "NUMERIC_PRECISION_RADIX",

CAST(
information_schema_tsql._pgtsql_numeric_scale(tsql_type_name, true_typid, true_typmod)
AS int)
AS "NUMERIC_SCALE",

CAST(
information_schema_tsql._pgtsql_datetime_precision(tsql_type_name, true_typmod)
AS smallint)
AS "DATETIME_PRECISION",

CAST(null AS sys.nvarchar(128)) AS "CHARACTER_SET_CATALOG",
CAST(null AS sys.nvarchar(128)) AS "CHARACTER_SET_SCHEMA",
/*
* TODO: We need to first create mapping of collation name to char-set name;
* Until then return null.
*/
CAST(null AS sys.nvarchar(128)) AS "CHARACTER_SET_NAME",

CAST(NULL as sys.nvarchar(128)) AS "COLLATION_CATALOG",
CAST(NULL as sys.nvarchar(128)) AS "COLLATION_SCHEMA",

/* Returns Babelfish specific collation name. */
CAST(co.collname AS sys.nvarchar(128)) AS "COLLATION_NAME",

CAST(CASE WHEN t.typtype = 'd' AND nt.nspname <> 'pg_catalog' AND nt.nspname <> 'sys'
THEN nc.dbname ELSE null END
AS sys.nvarchar(128)) AS "DOMAIN_CATALOG",
CAST(CASE WHEN t.typtype = 'd' AND nt.nspname <> 'pg_catalog' AND nt.nspname <> 'sys'
THEN ext.orig_name ELSE null END
AS sys.nvarchar(128)) AS "DOMAIN_SCHEMA",
CAST(CASE WHEN t.typtype = 'd' AND nt.nspname <> 'pg_catalog' AND nt.nspname <> 'sys'
THEN t.typname ELSE null END
AS sys.nvarchar(128)) AS "DOMAIN_NAME"

FROM (pg_attribute a LEFT JOIN pg_attrdef ad ON attrelid = adrelid AND attnum = adnum)
JOIN (pg_class c JOIN sys.pg_namespace_ext nc ON (c.relnamespace = nc.oid)) ON a.attrelid = c.oid
JOIN (pg_type t JOIN pg_namespace nt ON (t.typnamespace = nt.oid)) ON a.atttypid = t.oid
LEFT JOIN (pg_type bt JOIN pg_namespace nbt ON (bt.typnamespace = nbt.oid))
ON (t.typtype = 'd' AND t.typbasetype = bt.oid)
LEFT JOIN pg_collation co on co.oid = a.attcollation
LEFT OUTER JOIN sys.babelfish_namespace_ext ext on nc.nspname = ext.nspname,
information_schema_tsql._pgtsql_truetypid(nt, a, t) AS true_typid,
information_schema_tsql._pgtsql_truetypmod(nt, a, t) AS true_typmod,
sys.translate_pg_type_to_tsql(true_typid) AS tsql_type_name

WHERE (NOT pg_is_other_temp_schema(nc.oid))
AND a.attnum > 0 AND NOT a.attisdropped
AND c.relkind IN ('r', 'v', 'p')
AND (pg_has_role(c.relowner, 'USAGE')
OR has_column_privilege(c.oid, a.attnum,
'SELECT, INSERT, UPDATE, REFERENCES'))
AND ext.dbid = cast(sys.db_id() as oid);

GRANT SELECT ON information_schema_tsql.columns TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.datename(IN dp PG_CATALOG.TEXT, IN arg anyelement) RETURNS TEXT AS
$BODY$
SELECT
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,10 @@ GO
CREATE TABLE isc_columns_vu_prepare_nums(a INT, b SMALLINT, c TINYINT, d BIGINT, e BIT, f FLOAT, g REAL, h NUMERIC(5,3), i MONEY, j SMALLMONEY)
GO

-- test bytea datatype
CREATE TABLE isc_columns_vu_prepare_bytea(a bytea, b image)
GO

-- test with different db
CREATE DATABASE isc_columns_db1
GO
Expand Down Expand Up @@ -49,3 +53,8 @@ GO
CREATE VIEW isc_columns_vu_prepare_v1 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME LIKE '%isc_columns_UDT%' ORDER BY DATA_TYPE,COLUMN_NAME
GO

-- dep view
CREATE VIEW isc_columns_bytea_v2 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME = 'isc_columns_vu_prepare_bytea' ORDER BY DATA_TYPE,COLUMN_NAME
GO
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,10 @@ GO
CREATE TABLE isc_columns_vu_prepare_nums(a INT, b SMALLINT, c TINYINT, d BIGINT, e BIT, f FLOAT, g REAL, h NUMERIC(5,3), i MONEY, j SMALLMONEY)
GO

-- test bytea datatype
CREATE TABLE isc_columns_vu_prepare_bytea(a bytea, b image)
GO

-- test with different db
CREATE DATABASE isc_columns_db1
GO
Expand Down Expand Up @@ -49,3 +53,8 @@ GO
CREATE VIEW isc_columns_vu_prepare_v1 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME LIKE '%isc_columns_UDT%' ORDER BY DATA_TYPE,COLUMN_NAME
GO

-- dep view
CREATE VIEW isc_columns_bytea_v2 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME = 'isc_columns_vu_prepare_bytea' ORDER BY DATA_TYPE,COLUMN_NAME
GO
1 change: 1 addition & 0 deletions test/JDBC/expected/BABEL-SPCOLUMNS-vu-cleanup.out
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ drop table babel_sp_columns_vu_prepare_t_int
drop table babel_sp_columns_vu_prepare_t_text
drop table babel_sp_columns_vu_prepare_t_time
drop table babel_sp_columns_vu_prepare_t_money
drop table babel_sp_columns_vu_prepare_bytea
GO

USE master
Expand Down
3 changes: 3 additions & 0 deletions test/JDBC/expected/BABEL-SPCOLUMNS-vu-prepare.out
Original file line number Diff line number Diff line change
Expand Up @@ -15,3 +15,6 @@ GO

CREATE table babel_sp_columns_vu_prepare_t_money(a money)
GO

CREATE table babel_sp_columns_vu_prepare_bytea(a bytea, b image)
GO
10 changes: 10 additions & 0 deletions test/JDBC/expected/BABEL-SPCOLUMNS-vu-verify.out
Original file line number Diff line number Diff line change
Expand Up @@ -124,3 +124,13 @@ GO
varchar#!#varchar#!#varchar#!#varchar#!#smallint#!#varchar#!#int#!#int#!#smallint#!#smallint#!#smallint#!#varchar#!#nvarchar#!#smallint#!#smallint#!#int#!#int#!#varchar#!#smallint#!#smallint#!#smallint#!#smallint#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#int
~~END~~


-- test sp_columns_100 for bytea
EXEC [sys].sp_columns_100 'babel_sp_columns_vu_prepare_bytea', 'dbo', NULL, NULL, @ODBCVer = 3, @fUsePattern = 1;
GO
~~START~~
varchar#!#varchar#!#varchar#!#varchar#!#smallint#!#varchar#!#int#!#int#!#smallint#!#smallint#!#smallint#!#varchar#!#nvarchar#!#smallint#!#smallint#!#int#!#int#!#varchar#!#smallint#!#smallint#!#smallint#!#smallint#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#varchar#!#int
babel_sp_columns_vu_prepare_mydb1#!#dbo#!#babel_sp_columns_vu_prepare_bytea#!#a#!#-4#!#bytea#!#0#!#-1#!#<NULL>#!#<NULL>#!#1#!#<NULL>#!#<NULL>#!#-4#!#<NULL>#!#<NULL>#!#1#!#YES#!#0#!#0#!#0#!#0#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#34
babel_sp_columns_vu_prepare_mydb1#!#dbo#!#babel_sp_columns_vu_prepare_bytea#!#b#!#-4#!#image#!#2147483647#!#2147483647#!#<NULL>#!#<NULL>#!#1#!#<NULL>#!#<NULL>#!#-4#!#<NULL>#!#2147483647#!#2#!#YES#!#0#!#0#!#0#!#0#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#<NULL>#!#34
~~END~~

4 changes: 4 additions & 0 deletions test/JDBC/expected/ISC-Columns-vu-cleanup.out
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,9 @@ GO
DROP VIEW isc_columns_vu_prepare_v1
GO

DROP VIEW isc_columns_bytea_v2
GO

DROP FUNCTION isc_columns_vu_prepare_f2
DROP FUNCTION isc_columns_vu_prepare_f1
GO
Expand All @@ -19,4 +22,5 @@ GO
DROP TABLE isc_columns_vu_prepare_var
DROP TABLE isc_columns_vu_prepare_dates
DROP TABLE isc_columns_vu_prepare_nums
DROP TABLE isc_columns_vu_prepare_bytea
GO
9 changes: 9 additions & 0 deletions test/JDBC/expected/ISC-Columns-vu-prepare.out
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,10 @@ GO
CREATE TABLE isc_columns_vu_prepare_nums(a INT, b SMALLINT, c TINYINT, d BIGINT, e BIT, f FLOAT, g REAL, h NUMERIC(5,3), i MONEY, j SMALLMONEY)
GO

-- test bytea datatype
CREATE TABLE isc_columns_vu_prepare_bytea(a bytea, b image)
GO

-- test with different db
CREATE DATABASE isc_columns_db1
GO
Expand Down Expand Up @@ -49,3 +53,8 @@ GO
CREATE VIEW isc_columns_vu_prepare_v1 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME LIKE '%isc_columns_UDT%' ORDER BY DATA_TYPE,COLUMN_NAME
GO

-- dep view
CREATE VIEW isc_columns_bytea_v2 AS
SELECT * FROM information_schema.columns WHERE TABLE_NAME = 'isc_columns_vu_prepare_bytea' ORDER BY DATA_TYPE,COLUMN_NAME
GO
Loading

0 comments on commit f3730eb

Please sign in to comment.