From d262e9dd04d69ece5280b74b3aa4552b11241c47 Mon Sep 17 00:00:00 2001 From: Shalini Lohia Date: Sun, 5 Jan 2025 04:53:54 +0000 Subject: [PATCH] Improve performance of sys.sp_column_privileges by removing an unutilized check --- .../babelfishpg_tsql/sql/babelfishpg_tsql.sql | 59 ++++++------------- .../babelfishpg_tsql--4.4.0--5.0.0.sql | 59 ++++++------------- 2 files changed, 34 insertions(+), 84 deletions(-) diff --git a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql index fa07aee525..c5199ecb4d 100644 --- a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql +++ b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql @@ -1354,7 +1354,7 @@ BEGIN 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; +$$ LANGUAGE plpgsql STABLE PARALLEL SAFE; CREATE OR REPLACE VIEW sys.sp_column_privileges_view AS SELECT @@ -1385,46 +1385,21 @@ BEGIN IF (COALESCE(@table_owner, '') = '') BEGIN - - IF EXISTS ( - SELECT * FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) and pg_catalog.lower(SCHEMA_NAME()) = pg_catalog.lower(table_qualifier) - ) - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - COLUMN_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE - FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) - AND (pg_catalog.lower(SCHEMA_NAME()) = pg_catalog.lower(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END - ELSE - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - COLUMN_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE - FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) - AND (pg_catalog.lower('dbo')= pg_catalog.lower(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + COLUMN_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE + FROM sys.sp_column_privileges_view + WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) + AND (pg_catalog.lower('dbo')= pg_catalog.lower(table_owner)) + AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) + AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) + ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; END ELSE BEGIN @@ -1475,7 +1450,7 @@ BEGIN JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name WHERE t4.privilege_type = 'DELETE'; END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql STABLE PARALLEL SAFE; 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) diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql index d7ea026c72..6dd202ddb3 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--5.0.0.sql @@ -772,7 +772,7 @@ BEGIN 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; +$$ LANGUAGE plpgsql STABLE PARALLEL SAFE; CREATE OR REPLACE VIEW sys.sp_column_privileges_view AS SELECT @@ -802,46 +802,21 @@ BEGIN IF (COALESCE(@table_owner, '') = '') BEGIN - - IF EXISTS ( - SELECT * FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) and pg_catalog.lower(SCHEMA_NAME()) = pg_catalog.lower(table_qualifier) - ) - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - COLUMN_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE - FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) - AND (pg_catalog.lower(SCHEMA_NAME()) = pg_catalog.lower(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END - ELSE - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - COLUMN_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE - FROM sys.sp_column_privileges_view - WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) - AND (pg_catalog.lower('dbo')= pg_catalog.lower(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + COLUMN_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE + FROM sys.sp_column_privileges_view + WHERE pg_catalog.lower(@table_name) = pg_catalog.lower(table_name) + AND (pg_catalog.lower('dbo')= pg_catalog.lower(table_owner)) + AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR pg_catalog.lower(table_qualifier) = pg_catalog.lower(@table_qualifier)) + AND ((SELECT COALESCE(@column_name,'')) = '' OR pg_catalog.lower(column_name) LIKE pg_catalog.lower(@column_name)) + ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; END ELSE BEGIN @@ -892,7 +867,7 @@ BEGIN JOIN information_schema.table_privileges t4 ON t1.relname = t4.table_name WHERE t4.privilege_type = 'DELETE'; END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql STABLE PARALLEL SAFE; 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)