Skip to content

Commit

Permalink
Fixed issue in SP_TABLES() when @table_name parameter has square brac…
Browse files Browse the repository at this point in the history
…kets around underscore (babelfish-for-postgresql#2946)

Currently, SP_TABLES procedure does not support wild card [], which matches to any character that is specified in
square bracket. Due to this SP_TABLES procedure returns different output when @table_name parameter value is
table_1 and table[_]1. This issue exists because previously we were using helper function sp_tables_internal whose
body language was plpgsql hence we were using PostgresSQL Like operator for comparison, which does not support
square bracket wild card expression. Fixed the issue by removing this helper function and migrating this function logic
inside the SP_TABLES procedure whose language is pltsql and Like operator in pltsql supports square bracket wild card.

Task: BABEL-4128
Signed-off-by: Rohit Bhagat <[email protected]>
  • Loading branch information
rohit01010 authored Sep 19, 2024
1 parent 81d3cb4 commit 8edc110
Show file tree
Hide file tree
Showing 13 changed files with 529 additions and 71 deletions.
98 changes: 34 additions & 64 deletions contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -984,63 +984,6 @@ AND has_schema_privilege(t1.relnamespace, 'USAGE')
AND has_table_privilege(t1.oid, 'SELECT,INSERT,UPDATE,DELETE,TRUNCATE,TRIGGER');
GRANT SELECT ON sys.sp_tables_view TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.sp_tables_internal(
in_table_name sys.nvarchar(384) = NULL,
in_table_owner sys.nvarchar(384) = NULL,
in_table_qualifier sys.sysname = NULL,
in_table_type sys.varchar(100) = NULL,
in_fusepattern sys.bit = '1')
RETURNS TABLE (
out_table_qualifier sys.sysname,
out_table_owner sys.sysname,
out_table_name sys.sysname,
out_table_type sys.varchar(32),
out_remarks sys.varchar(254)
)
AS $$
DECLARE opt_table sys.varchar(16) = '';
DECLARE opt_view sys.varchar(16) = '';
DECLARE cs_as_in_table_type varchar COLLATE "C" = in_table_type;
BEGIN
IF upper(cs_as_in_table_type) LIKE '%''TABLE''%' THEN
opt_table = 'TABLE';
END IF;
IF upper(cs_as_in_table_type) LIKE '%''VIEW''%' THEN
opt_view = 'VIEW';
END IF;
IF in_fusepattern = 1 THEN
RETURN query
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
CAST(remarks AS sys.varchar(254)) AS REMARKS
FROM sys.sp_tables_view
WHERE (in_table_name IS NULL OR table_name LIKE in_table_name collate sys.database_default)
AND (in_table_owner IS NULL OR table_owner LIKE in_table_owner collate sys.database_default)
AND (in_table_qualifier IS NULL OR table_qualifier LIKE in_table_qualifier collate sys.database_default)
AND (cs_as_in_table_type IS NULL OR table_type = opt_table OR table_type = opt_view)
ORDER BY table_qualifier, table_owner, table_name;
ELSE
RETURN query
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
CAST(remarks AS sys.varchar(254)) AS REMARKS
FROM sys.sp_tables_view
WHERE (in_table_name IS NULL OR table_name = in_table_name collate sys.database_default)
AND (in_table_owner IS NULL OR table_owner = in_table_owner collate sys.database_default)
AND (in_table_qualifier IS NULL OR table_qualifier = in_table_qualifier collate sys.database_default)
AND (cs_as_in_table_type IS NULL OR table_type = opt_table OR table_type = opt_view)
ORDER BY table_qualifier, table_owner, table_name;
END IF;
END;
$$
LANGUAGE plpgsql STABLE;

CREATE OR REPLACE PROCEDURE sys.sp_tables (
"@table_name" sys.nvarchar(384) = NULL,
"@table_owner" sys.nvarchar(384) = NULL,
Expand Down Expand Up @@ -1069,13 +1012,40 @@ BEGIN
THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1;
END

SELECT
CAST(out_table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(out_table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(out_table_name AS sys.sysname) AS TABLE_NAME,
CAST(out_table_type AS sys.varchar(32)) AS TABLE_TYPE,
CAST(out_remarks AS sys.varchar(254)) AS REMARKS
FROM sys.sp_tables_internal(@table_name, @table_owner, @table_qualifier, CAST(@table_type AS varchar(100)), @fusepattern);
IF (@fusepattern = 1)
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
remarks AS REMARKS
FROM sys.sp_tables_view
WHERE (@table_name IS NULL OR table_name LIKE @table_name collate database_default)
AND (@table_owner IS NULL OR table_owner LIKE @table_owner collate database_default)
AND (@table_qualifier IS NULL OR table_qualifier LIKE @table_qualifier collate database_default)
AND (
@table_type IS NULL OR
(CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR
(CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default)
)
ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME;
ELSE
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
remarks AS REMARKS
FROM sys.sp_tables_view
WHERE (@table_name IS NULL OR table_name = @table_name collate database_default)
AND (@table_owner IS NULL OR table_owner = @table_owner collate database_default)
AND (@table_qualifier IS NULL OR table_qualifier = @table_qualifier collate database_default)
AND (
@table_type IS NULL OR
(CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR
(CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default)
)
ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME;
END;
$$
LANGUAGE 'pltsql';
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,33 @@
-- add 'sys' to search path for the convenience
SELECT set_config('search_path', 'sys, '||current_setting('search_path'), false);

-- Drops an object if it does not have any dependent objects.
-- Is a temporary procedure for use by the upgrade script. Will be dropped at the end of the upgrade.
-- Please have this be one of the first statements executed in this upgrade script.
CREATE OR REPLACE PROCEDURE babelfish_drop_deprecated_object(object_type varchar, schema_name varchar, object_name varchar) AS
$$
DECLARE
error_msg text;
query1 text;
query2 text;
BEGIN

query1 := pg_catalog.format('alter extension babelfishpg_tsql drop %s %s.%s', object_type, schema_name, object_name);
query2 := pg_catalog.format('drop %s %s.%s', object_type, schema_name, object_name);

execute query1;
execute query2;
EXCEPTION
when object_not_in_prerequisite_state then --if 'alter extension' statement fails
GET STACKED DIAGNOSTICS error_msg = MESSAGE_TEXT;
raise warning '%', error_msg;
when dependent_objects_still_exist then --if 'drop view' statement fails
GET STACKED DIAGNOSTICS error_msg = MESSAGE_TEXT;
raise warning '%', error_msg;
end
$$
LANGUAGE plpgsql;

-- Please add your SQLs here
/*
* Note: These SQL statements may get executed multiple times specially when some features get backpatched.
Expand Down Expand Up @@ -113,6 +140,81 @@ AND pg_get_serial_sequence(quote_ident(ext.nspname)||'.'||quote_ident(c.relname)
AND has_sequence_privilege(pg_get_serial_sequence(quote_ident(ext.nspname)||'.'||quote_ident(c.relname), a.attname), 'USAGE,SELECT,UPDATE');
GRANT SELECT ON sys.identity_columns TO PUBLIC;

CREATE OR REPLACE PROCEDURE sys.sp_tables (
"@table_name" sys.nvarchar(384) = NULL,
"@table_owner" sys.nvarchar(384) = NULL,
"@table_qualifier" sys.sysname = NULL,
"@table_type" sys.nvarchar(100) = NULL,
"@fusepattern" sys.bit = '1')
AS $$
BEGIN

-- Handle special case: Enumerate all databases when name and owner are blank but qualifier is '%'
IF (@table_qualifier = '%' AND @table_owner = '' AND @table_name = '')
BEGIN
SELECT
d.name AS TABLE_QUALIFIER,
CAST(NULL AS sys.sysname) AS TABLE_OWNER,
CAST(NULL AS sys.sysname) AS TABLE_NAME,
CAST(NULL AS sys.varchar(32)) AS TABLE_TYPE,
CAST(NULL AS sys.varchar(254)) AS REMARKS
FROM sys.databases d ORDER BY TABLE_QUALIFIER;

RETURN;
END;

IF (@table_qualifier != '' AND LOWER(@table_qualifier) != LOWER(sys.db_name()))
BEGIN
THROW 33557097, N'The database name component of the object qualifier must be the name of the current database.', 1;
END

IF (@fusepattern = 1)
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
remarks AS REMARKS
FROM sys.sp_tables_view
WHERE (@table_name IS NULL OR table_name LIKE @table_name collate database_default)
AND (@table_owner IS NULL OR table_owner LIKE @table_owner collate database_default)
AND (@table_qualifier IS NULL OR table_qualifier LIKE @table_qualifier collate database_default)
AND (
@table_type IS NULL OR
(CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR
(CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default)
)
ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME;
ELSE
SELECT
CAST(table_qualifier AS sys.sysname) AS TABLE_QUALIFIER,
CAST(table_owner AS sys.sysname) AS TABLE_OWNER,
CAST(table_name AS sys.sysname) AS TABLE_NAME,
CAST(table_type AS sys.varchar(32)) AS TABLE_TYPE,
remarks AS REMARKS
FROM sys.sp_tables_view
WHERE (@table_name IS NULL OR table_name = @table_name collate database_default)
AND (@table_owner IS NULL OR table_owner = @table_owner collate database_default)
AND (@table_qualifier IS NULL OR table_qualifier = @table_qualifier collate database_default)
AND (
@table_type IS NULL OR
(CAST(@table_type AS varchar(100)) LIKE '%''TABLE''%' collate database_default AND table_type = 'TABLE' collate database_default) OR
(CAST(@table_type AS varchar(100)) LIKE '%''VIEW''%' collate database_default AND table_type = 'VIEW' collate database_default)
)
ORDER BY TABLE_QUALIFIER, TABLE_OWNER, TABLE_NAME;
END;
$$
LANGUAGE 'pltsql';
GRANT EXECUTE ON PROCEDURE sys.sp_tables TO PUBLIC;

ALTER FUNCTION sys.sp_tables_internal RENAME TO sp_tables_internal_deprecated_in_3_8_0;

CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'sp_tables_internal_deprecated_in_3_8_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);

-- After upgrade, always run analyze for all babelfish catalogs.
CALL sys.analyze_babelfish_catalogs();

Expand Down
6 changes: 6 additions & 0 deletions test/JDBC/expected/BABEL-SP_TABLES-vu-cleanup.out
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,12 @@ drop view babel_sp_tables_vu_prepare_t_sptables5
go
drop table babel_sp_tables_vu_prepare_t_sptables
go
drop table babel_sp_tables_vu_prepare_t_s_tables2
go
drop table babel_sp_tables_vu_prepare_t__tables2
go
drop table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables
go
drop table babel_sp_tables_vu_prepare_MyTable1
go
drop table [babel_sp_tables_vu_prepare_MyTable2]
Expand Down
6 changes: 6 additions & 0 deletions test/JDBC/expected/BABEL-SP_TABLES-vu-prepare.out
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,12 @@ create table babel_sp_tables_vu_prepare_t_sptables2(b int)
go
create table babel_sp_tables_vu_prepare_t_sotables2(c int)
go
create table babel_sp_tables_vu_prepare_t_s_tables2(c int)
go
create table babel_sp_tables_vu_prepare_t__tables2(c int)
go
create table babel_sp_tables_vu_prepare_test_escape_chars_sp_tables(c int)
go
create table babel_sp_tables_vu_prepare_MyTable1 (a int, b int, c int)
go
create table [babel_sp_tables_vu_prepare_MyTable2] ([a] int, [b] int, [c] int)
Expand Down
Loading

0 comments on commit 8edc110

Please sign in to comment.