Skip to content

Commit

Permalink
Performance improvement for the views sys.sp_column_privileges_view a…
Browse files Browse the repository at this point in the history
…nd sys.sp_table_privileges_view (babelfish-for-postgresql#3234)

Create internal functions for the views sys.sp_column_privileges_view and sys.sp_table_privileges_view to improve the performance by analysing the query plan. The performance degradation was caused by inaccurate row estimates resulting from an extra JOIN with babelfishpg_authid_user_ext table, leading to suboptimal query plans.

Fixed upgrade workflow by using correct source versions.

Task: BABEL-5353

Signed-off-by: Shalini Lohia [email protected]
  • Loading branch information
shalinilohia50 authored Dec 13, 2024
1 parent 0edbfa2 commit 72156f8
Show file tree
Hide file tree
Showing 6 changed files with 150 additions and 63 deletions.
100 changes: 71 additions & 29 deletions contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1326,23 +1326,48 @@ $$
LANGUAGE PLPGSQL;
GRANT ALL on FUNCTION sys.babelfish_runtime_error TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.sp_column_privileges_internal()
RETURNS TABLE (
TABLE_QUALIFIER sys.sysname,
TABLE_OWNER sys.sysname,
TABLE_NAME sys.sysname,
COLUMN_NAME sys.sysname,
GRANTOR sys.sysname,
GRANTEE sys.sysname,
PRIVILEGE sys.varchar(32),
IS_GRANTABLE sys.varchar(3)
) AS $$
BEGIN
RETURN QUERY
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST(COALESCE(SPLIT_PART(t6.attoptions[1], '=', 2), t5.column_name) AS sys.sysname) AS COLUMN_NAME,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t5.grantor::name) AS sys.sysname) AS GRANTOR,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t5.grantee::name) AS sys.sysname) AS GRANTEE,
CAST(t5.privilege_type AS sys.varchar(32)) COLLATE sys.database_default AS PRIVILEGE,
CAST(t5.is_grantable AS sys.varchar(3)) COLLATE sys.database_default AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE VIEW sys.sp_column_privileges_view AS
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST(COALESCE(SPLIT_PART(t6.attoptions[1], '=', 2), t5.column_name) AS sys.sysname) AS COLUMN_NAME,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantor::name) AS sys.sysname) AS GRANTOR,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantee::name) AS sys.sysname) AS GRANTEE,
CAST(t5.privilege_type AS sys.varchar(32)) COLLATE sys.database_default AS PRIVILEGE,
CAST(t5.is_grantable AS sys.varchar(3)) COLLATE sys.database_default AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t5.grantee
WHERE ext.orig_username NOT IN ('db_datawriter', 'db_datareader');
CAST(TABLE_QUALIFIER AS sys.sysname),
CAST(TABLE_OWNER AS sys.sysname),
CAST(TABLE_NAME AS sys.sysname),
CAST(COLUMN_NAME AS sys.sysname),
CAST(GRANTOR AS sys.sysname),
CAST(GRANTEE AS sys.sysname),
CAST(PRIVILEGE AS sys.varchar(32)),
CAST(IS_GRANTABLE AS sys.varchar(3))
FROM sys.sp_column_privileges_internal()
WHERE GRANTEE NOT IN ('db_datareader', 'db_datawriter');
GRANT SELECT ON sys.sp_column_privileges_view TO PUBLIC;

CREATE OR REPLACE PROCEDURE sys.sp_column_privileges(
Expand Down Expand Up @@ -1424,6 +1449,34 @@ $$
LANGUAGE 'pltsql';
GRANT EXECUTE ON PROCEDURE sys.sp_column_privileges TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.sp_table_privileges_internal()
RETURNS TABLE (
TABLE_QUALIFIER sys.sysname,
TABLE_OWNER sys.sysname,
TABLE_NAME sys.sysname,
GRANTOR sys.sysname,
GRANTEE sys.sysname,
PRIVILEGE sys.sysname,
IS_GRANTABLE sys.sysname
) AS $$
BEGIN
RETURN QUERY
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t4.grantor) AS sys.sysname) AS GRANTOR,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t4.grantee) AS sys.sysname) AS GRANTEE,
CAST(t4.privilege_type AS sys.sysname) AS PRIVILEGE,
CAST(t4.is_grantable AS sys.sysname) AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
WHERE t4.privilege_type = 'DELETE';
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE VIEW sys.sp_table_privileges_view AS
-- Will use sp_column_priivleges_view to get information from SELECT, INSERT and REFERENCES (only need permission from 1 column in table)
SELECT DISTINCT
Expand All @@ -1438,20 +1491,9 @@ FROM sys.sp_column_privileges_view

UNION
-- We need these set of joins only for the DELETE privilege
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t4.grantor) AS sys.sysname) AS GRANTOR,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t4.grantee) AS sys.sysname) AS GRANTEE,
CAST(t4.privilege_type AS sys.sysname) AS PRIVILEGE,
CAST(t4.is_grantable AS sys.sysname) AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t4.grantee
WHERE t4.privilege_type = 'DELETE' AND ext.orig_username != 'db_datawriter';
SELECT *
FROM sys.sp_table_privileges_internal()
WHERE GRANTEE != 'db_datawriter';
GRANT SELECT on sys.sp_table_privileges_view TO PUBLIC;

CREATE OR REPLACE PROCEDURE sys.sp_table_privileges(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -684,23 +684,48 @@ LANGUAGE 'pltsql';

GRANT EXECUTE on PROCEDURE sys.sp_helpuser TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.sp_column_privileges_internal()
RETURNS TABLE (
TABLE_QUALIFIER sys.sysname,
TABLE_OWNER sys.sysname,
TABLE_NAME sys.sysname,
COLUMN_NAME sys.sysname,
GRANTOR sys.sysname,
GRANTEE sys.sysname,
PRIVILEGE sys.varchar(32),
IS_GRANTABLE sys.varchar(3)
) AS $$
BEGIN
RETURN QUERY
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST(COALESCE(SPLIT_PART(t6.attoptions[1], '=', 2), t5.column_name) AS sys.sysname) AS COLUMN_NAME,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t5.grantor::name) AS sys.sysname) AS GRANTOR,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t5.grantee::name) AS sys.sysname) AS GRANTEE,
CAST(t5.privilege_type AS sys.varchar(32)) COLLATE sys.database_default AS PRIVILEGE,
CAST(t5.is_grantable AS sys.varchar(3)) COLLATE sys.database_default AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE VIEW sys.sp_column_privileges_view AS
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST(COALESCE(SPLIT_PART(t6.attoptions[1], '=', 2), t5.column_name) AS sys.sysname) AS COLUMN_NAME,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantor::name) AS sys.sysname) AS GRANTOR,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t5.grantee::name) AS sys.sysname) AS GRANTEE,
CAST(t5.privilege_type AS sys.varchar(32)) COLLATE sys.database_default AS PRIVILEGE,
CAST(t5.is_grantable AS sys.varchar(3)) COLLATE sys.database_default AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.column_privileges t5 ON t1.relname = t5.table_name AND t2.nspname = t5.table_schema
JOIN pg_attribute t6 ON t6.attrelid = t1.oid AND t6.attname = t5.column_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t5.grantee
WHERE ext.orig_username NOT IN ('db_datawriter', 'db_datareader');
CAST(TABLE_QUALIFIER AS sys.sysname),
CAST(TABLE_OWNER AS sys.sysname),
CAST(TABLE_NAME AS sys.sysname),
CAST(COLUMN_NAME AS sys.sysname),
CAST(GRANTOR AS sys.sysname),
CAST(GRANTEE AS sys.sysname),
CAST(PRIVILEGE AS sys.varchar(32)),
CAST(IS_GRANTABLE AS sys.varchar(3))
FROM sys.sp_column_privileges_internal()
WHERE GRANTEE NOT IN ('db_datareader', 'db_datawriter');

CREATE OR REPLACE PROCEDURE sys.sp_column_privileges(
"@table_name" sys.sysname,
Expand Down Expand Up @@ -779,9 +804,36 @@ BEGIN
END;
$$
LANGUAGE 'pltsql';

GRANT EXECUTE ON PROCEDURE sys.sp_column_privileges TO PUBLIC;

CREATE OR REPLACE FUNCTION sys.sp_table_privileges_internal()
RETURNS TABLE (
TABLE_QUALIFIER sys.sysname,
TABLE_OWNER sys.sysname,
TABLE_NAME sys.sysname,
GRANTOR sys.sysname,
GRANTEE sys.sysname,
PRIVILEGE sys.sysname,
IS_GRANTABLE sys.sysname
) AS $$
BEGIN
RETURN QUERY
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t4.grantor) AS sys.sysname) AS GRANTOR,
CAST((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = t4.grantee) AS sys.sysname) AS GRANTEE,
CAST(t4.privilege_type AS sys.sysname) AS PRIVILEGE,
CAST(t4.is_grantable AS sys.sysname) AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
WHERE t4.privilege_type = 'DELETE';
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE VIEW sys.sp_table_privileges_view AS
-- Will use sp_column_priivleges_view to get information from SELECT, INSERT and REFERENCES (only need permission from 1 column in table)
SELECT DISTINCT
Expand All @@ -793,22 +845,13 @@ CAST(GRANTEE AS sys.sysname) AS GRANTEE,
CAST(PRIVILEGE AS sys.sysname) COLLATE sys.database_default AS PRIVILEGE,
CAST(IS_GRANTABLE AS sys.sysname) COLLATE sys.database_default AS IS_GRANTABLE
FROM sys.sp_column_privileges_view

UNION
-- We need these set of joins only for the DELETE privilege
SELECT
CAST(t2.dbname AS sys.sysname) AS TABLE_QUALIFIER,
CAST(s1.name AS sys.sysname) AS TABLE_OWNER,
CAST(t1.relname AS sys.sysname) AS TABLE_NAME,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t4.grantor) AS sys.sysname) AS GRANTOR,
CAST((select orig_username from sys.babelfish_authid_user_ext where rolname = t4.grantee) AS sys.sysname) AS GRANTEE,
CAST(t4.privilege_type AS sys.sysname) AS PRIVILEGE,
CAST(t4.is_grantable AS sys.sysname) AS IS_GRANTABLE
FROM pg_catalog.pg_class t1
JOIN sys.pg_namespace_ext t2 ON t1.relnamespace = t2.oid
JOIN sys.schemas s1 ON s1.schema_id = t1.relnamespace
JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name
JOIN sys.babelfish_authid_user_ext ext ON ext.rolname = t4.grantee
WHERE t4.privilege_type = 'DELETE' AND ext.orig_username != 'db_datawriter';
SELECT *
FROM sys.sp_table_privileges_internal()
WHERE GRANTEE != 'db_datawriter';

CREATE OR REPLACE PROCEDURE sys.sp_table_privileges(
"@table_name" sys.nvarchar(384),
"@table_owner" sys.nvarchar(384) = '',
Expand Down Expand Up @@ -855,7 +898,6 @@ BEGIN
END;
$$
LANGUAGE 'pltsql';

GRANT EXECUTE ON PROCEDURE sys.sp_table_privileges TO PUBLIC;

-- sp_helpsrvrolemember
Expand Down
2 changes: 0 additions & 2 deletions test/JDBC/input/BABEL-SP_COLUMN_PRIVILEGES.mix
Original file line number Diff line number Diff line change
@@ -1,5 +1,3 @@
-- sla 160000
-- sla_for_parallel_query_enforced 160000
-- tsql
CREATE DATABASE db1
GO
Expand Down
1 change: 0 additions & 1 deletion test/JDBC/input/BABEL-SP_TABLE_PRIVILIGES-vu-verify.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
-- sla 160000
use babel_sp_table_priviliges_vu_prepare_db1
go

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,6 +36,7 @@ Could not find tests for function sys.patindex_ai_collations
Could not find tests for function sys.pltsql_assign_var
Could not find tests for function sys.remove_accents_internal_using_cache
Could not find tests for function sys.role_id
Could not find tests for function sys.sp_column_privileges_internal
Could not find tests for function sys.sp_columns_managed_internal
Could not find tests for function sys.sp_datatype_info_helper
Could not find tests for function sys.sp_describe_first_result_set_internal
Expand All @@ -45,6 +46,7 @@ Could not find tests for function sys.sp_releaseapplock_function
Could not find tests for function sys.sp_special_columns_length_helper
Could not find tests for function sys.sp_special_columns_precision_helper
Could not find tests for function sys.sp_special_columns_scale_helper
Could not find tests for function sys.sp_table_privileges_internal
Could not find tests for function sys.suser_id_internal
Could not find tests for function sys.suser_name_internal
Could not find tests for function sys.systypes_precision_helper
Expand Down Expand Up @@ -141,6 +143,7 @@ Could not find upgrade tests for function sys.pltsql_assign_var
Could not find upgrade tests for function sys.remove_accents_internal_using_cache
Could not find upgrade tests for function sys.role_id
Could not find upgrade tests for function sys.servername
Could not find upgrade tests for function sys.sp_column_privileges_internal
Could not find upgrade tests for function sys.sp_columns_managed_internal
Could not find upgrade tests for function sys.sp_datatype_info_helper
Could not find upgrade tests for function sys.sp_describe_first_result_set_internal
Expand All @@ -150,6 +153,7 @@ Could not find upgrade tests for function sys.sp_releaseapplock_function
Could not find upgrade tests for function sys.sp_special_columns_length_helper
Could not find upgrade tests for function sys.sp_special_columns_precision_helper
Could not find upgrade tests for function sys.sp_special_columns_scale_helper
Could not find upgrade tests for function sys.sp_table_privileges_internal
Could not find upgrade tests for function sys.suser_id_internal
Could not find upgrade tests for function sys.suser_name_internal
Could not find upgrade tests for function sys.systypes_precision_helper
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -625,6 +625,7 @@ Function sys.smallint_sqlvariant(smallint)
Function sys.smallmoney_sqlvariant(sys.smallmoney)
Function sys.smallmoneylarger(sys.smallmoney,sys.smallmoney)
Function sys.smallmoneysmaller(sys.smallmoney,sys.smallmoney)
Function sys.sp_column_privileges_internal()
Function sys.sp_columns_managed_internal(sys.nvarchar,sys.nvarchar,sys.nvarchar,sys.nvarchar,integer)
Function sys.sp_datatype_info_helper(smallint,boolean)
Function sys.sp_describe_first_result_set_internal(sys.nvarchar,sys.nvarchar,sys.tinyint)
Expand All @@ -634,6 +635,7 @@ Function sys.sp_releaseapplock_function(character varying,character varying,char
Function sys.sp_special_columns_length_helper(text,integer,smallint,bigint)
Function sys.sp_special_columns_precision_helper(text,integer,smallint,bigint)
Function sys.sp_special_columns_scale_helper(text,integer)
Function sys.sp_table_privileges_internal()
Function sys.sql_variant_property(sys.sql_variant,sys."varchar")
Function sys.sqlvariant_bbfbinary(sys.sql_variant)
Function sys.sqlvariant_bigint(sys.sql_variant)
Expand Down

0 comments on commit 72156f8

Please sign in to comment.