diff --git a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql index 8b4ae717e30..30aec2800af 100644 --- a/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql +++ b/contrib/babelfishpg_tsql/sql/babelfishpg_tsql.sql @@ -2122,7 +2122,7 @@ BEGIN LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner WHERE Ext1.database_name = DB_NAME() AND (Ext1.type != 'R' OR Ext1.type != 'A') - AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') + AND Ext1.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') ORDER BY UserName, RoleName; END -- If the security account is the db fixed role - db_owner @@ -2154,7 +2154,7 @@ BEGIN WHERE Ext1.database_name = DB_NAME() AND Ext2.database_name = DB_NAME() AND Ext1.type = 'R' - AND Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') + AND Ext2.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) ORDER BY Role_name, Users_in_role; END @@ -2192,7 +2192,7 @@ BEGIN LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner WHERE Ext1.database_name = DB_NAME() AND (Ext1.type != 'R' OR Ext1.type != 'A') - AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') + AND Ext1.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) ORDER BY UserName, RoleName; END @@ -2352,18 +2352,19 @@ CREATE OR REPLACE PROCEDURE sys.sp_helpdbfixedrole("@rolename" sys.SYSNAME = NUL $$ BEGIN -- Returns a list of the fixed database roles. - IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') + IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_securityadmin', 'db_datareader', 'db_datawriter') BEGIN SELECT CAST(DbFixedRole as sys.SYSNAME) AS DbFixedRole, CAST(Description AS sys.nvarchar(70)) AS Description FROM ( VALUES ('db_owner', 'DB Owners'), ('db_accessadmin', 'DB Access Administrators'), + ('db_securityadmin', 'DB Security Administrators'), ('db_datareader', 'DB Data Reader'), ('db_datawriter', 'DB Data Writer')) x(DbFixedRole, Description) WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole; END ELSE IF LOWER(RTRIM(@rolename)) IN ( - 'db_securityadmin','db_ddladmin', 'db_backupoperator', - 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter') + 'db_ddladmin', 'db_backupoperator', + 'db_denydatareader', 'db_denydatawriter') BEGIN -- Return an empty result set instead of raising an error SELECT CAST(NULL AS sys.SYSNAME) AS DbFixedRole, CAST(NULL AS sys.nvarchar(70)) AS Description diff --git a/contrib/babelfishpg_tsql/sql/ownership.sql b/contrib/babelfishpg_tsql/sql/ownership.sql index fe902ff840f..7e9e62a338e 100644 --- a/contrib/babelfishpg_tsql/sql/ownership.sql +++ b/contrib/babelfishpg_tsql/sql/ownership.sql @@ -260,10 +260,15 @@ LANGUAGE plpgsql AS $$ DECLARE reserved_roles varchar[] := ARRAY['sysadmin', 'securityadmin', 'dbcreator', - 'master_dbo', 'master_guest', 'master_db_owner', 'master_db_accessadmin', 'master_db_datareader', 'master_db_datawriter', - 'tempdb_dbo', 'tempdb_guest', 'tempdb_db_owner', 'tempdb_db_accessadmin', 'tempdb_db_datareader', 'tempdb_db_datawriter', - 'msdb_dbo', 'msdb_guest', 'msdb_db_owner', 'msdb_db_accessadmin', 'msdb_db_datareader', 'msdb_db_datawriter']; - + 'master_dbo', 'master_guest', 'master_db_owner', + 'master_db_accessadmin', 'master_db_securityadmin', + 'master_db_datareader', 'master_db_datawriter', + 'tempdb_dbo', 'tempdb_guest', 'tempdb_db_owner', + 'tempdb_db_accessadmin', 'tempdb_db_securityadmin', + 'tempdb_db_datareader', 'tempdb_db_datawriter', + 'msdb_dbo', 'msdb_guest', 'msdb_db_owner', + 'msdb_db_accessadmin', 'msdb_db_securityadmin', + 'msdb_db_datareader', 'msdb_db_datawriter']; user_id oid := -1; db_name name := NULL; role_name varchar; @@ -465,7 +470,7 @@ ON Base.rolname = Ext.rolname LEFT OUTER JOIN pg_catalog.pg_roles Base2 ON Ext.login_name = Base2.rolname WHERE Ext.database_name = DB_NAME() - AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter', 'guest') -- system users should always be visible + AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter', 'guest') -- system users should always be visible OR pg_has_role(Ext.rolname, 'MEMBER')) -- Current user should be able to see users it has permission of UNION ALL SELECT diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql index 21ca498af7a..51b0202cdc0 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.3.0--4.4.0.sql @@ -70,281 +70,6 @@ EXCEPTION WHEN OTHERS THEN END; $$; - -CREATE OR REPLACE PROCEDURE sys.create_db_roles_during_upgrade() -LANGUAGE C -AS 'babelfishpg_tsql', 'create_db_roles_during_upgrade'; - -CALL sys.create_db_roles_during_upgrade(); - -DROP PROCEDURE sys.create_db_roles_during_upgrade(); - -DO -LANGUAGE plpgsql -$$ -DECLARE - existing_server_roles TEXT; -BEGIN - SELECT STRING_AGG(rolname::text, ', ') - INTO existing_server_roles FROM pg_catalog.pg_roles - WHERE rolname IN ('securityadmin', 'dbcreator'); - - IF existing_server_roles IS NOT NULL THEN - RAISE EXCEPTION 'The following role(s) already exist(s): %', existing_server_roles; - ELSE - EXECUTE format('CREATE ROLE securityadmin CREATEROLE INHERIT PASSWORD NULL'); - EXECUTE format('GRANT securityadmin TO bbf_role_admin WITH ADMIN TRUE'); - CALL sys.babel_initialize_logins('securityadmin'); - EXECUTE format('CREATE ROLE dbcreator CREATEDB INHERIT PASSWORD NULL'); - EXECUTE format('GRANT dbcreator TO bbf_role_admin WITH ADMIN TRUE'); - CALL sys.babel_initialize_logins('dbcreator'); - END IF; -END; -$$; - -CREATE OR REPLACE FUNCTION sys.bbf_is_member_of_role_nosuper(OID, OID) -RETURNS BOOLEAN AS 'babelfishpg_tsql', 'bbf_is_member_of_role_nosuper' -LANGUAGE C STABLE STRICT PARALLEL SAFE; - --- SERVER_PRINCIPALS -CREATE OR REPLACE VIEW sys.server_principals -AS SELECT -CAST(Ext.orig_loginname AS sys.SYSNAME) AS name, -CAST(Base.oid As INT) AS principal_id, -CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, -CAST(Ext.type AS CHAR(1)) as type, -CAST( - CASE - WHEN Ext.type = 'S' THEN 'SQL_LOGIN' - WHEN Ext.type = 'R' THEN 'SERVER_ROLE' - WHEN Ext.type = 'U' THEN 'WINDOWS_LOGIN' - ELSE NULL - END - AS NVARCHAR(60)) AS type_desc, -CAST(Ext.is_disabled AS INT) AS is_disabled, -CAST(Ext.create_date AS SYS.DATETIME) AS create_date, -CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date, -CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.default_database_name END AS SYS.SYSNAME) AS default_database_name, -CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name, -CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.credential_id END AS INT) AS credential_id, -CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.owning_principal_id END AS INT) AS owning_principal_id, -CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.is_fixed_role END AS sys.BIT) AS is_fixed_role -FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname -WHERE (pg_has_role(suser_id(), 'sysadmin'::TEXT, 'MEMBER') - OR pg_has_role(suser_id(), 'securityadmin'::TEXT, 'MEMBER') - OR Ext.orig_loginname = suser_name() - OR Ext.orig_loginname = (SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = CURRENT_DATABASE()) COLLATE sys.database_default - OR Ext.type = 'R') - AND Ext.type != 'Z' -UNION ALL -SELECT -CAST('public' AS SYS.SYSNAME) AS name, -CAST(-1 AS INT) AS principal_id, -CAST(CAST(0 as INT) as sys.varbinary(85)) AS sid, -CAST('R' AS CHAR(1)) as type, -CAST('SERVER_ROLE' AS NVARCHAR(60)) AS type_desc, -CAST(0 AS INT) AS is_disabled, -CAST(NULL AS SYS.DATETIME) AS create_date, -CAST(NULL AS SYS.DATETIME) AS modify_date, -CAST(NULL AS SYS.SYSNAME) AS default_database_name, -CAST(NULL AS SYS.SYSNAME) AS default_language_name, -CAST(NULL AS INT) AS credential_id, -CAST(1 AS INT) AS owning_principal_id, -CAST(0 AS sys.BIT) AS is_fixed_role; - -GRANT SELECT ON sys.server_principals TO PUBLIC; - --- login_token -CREATE OR REPLACE VIEW sys.login_token -AS SELECT -CAST(Base.oid As INT) AS principal_id, -CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, -CAST(Ext.orig_loginname AS sys.nvarchar(128)) AS name, -CAST(CASE -WHEN Ext.type = 'U' THEN 'WINDOWS LOGIN' -ELSE 'SQL LOGIN' END AS SYS.NVARCHAR(128)) AS TYPE, -CAST('GRANT OR DENY' as sys.nvarchar(128)) as usage -FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname -WHERE Ext.orig_loginname = sys.suser_name() -AND Ext.type in ('S','U') -UNION ALL -SELECT -CAST(Base.oid As INT) AS principal_id, -CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, -CAST(Ext.orig_loginname AS sys.nvarchar(128)) AS name, -CAST('SERVER ROLE' AS sys.nvarchar(128)) AS type, -CAST ('GRANT OR DENY' as sys.nvarchar(128)) as usage -FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname -WHERE Ext.type = 'R' -AND bbf_is_member_of_role_nosuper(sys.suser_id(), Base.oid); - -GRANT SELECT ON sys.login_token TO PUBLIC; - -CREATE OR REPLACE FUNCTION is_srvrolemember(role sys.SYSNAME, login sys.SYSNAME DEFAULT suser_name()) -RETURNS INTEGER AS -$$ -DECLARE has_role BOOLEAN; -DECLARE login_valid BOOLEAN; -BEGIN - role := TRIM(trailing from LOWER(role)); - login := TRIM(trailing from LOWER(login)); - - login_valid = (login = suser_name() COLLATE sys.database_default) OR - (EXISTS (SELECT name - FROM sys.server_principals - WHERE - LOWER(name) = login COLLATE sys.database_default - AND type IN ('S', 'R'))); - - IF NOT login_valid THEN - RETURN NULL; - - ELSIF role = 'public' COLLATE sys.database_default THEN - RETURN 1; - - ELSIF role COLLATE sys.database_default IN ('sysadmin', 'securityadmin', 'dbcreator') THEN - has_role = (pg_has_role(login::TEXT, role::TEXT, 'MEMBER') - OR ((login COLLATE sys.database_default NOT IN ('sysadmin', 'securityadmin', 'dbcreator')) - AND pg_has_role(login::TEXT, 'sysadmin'::TEXT, 'MEMBER'))); - IF has_role THEN - RETURN 1; - ELSE - RETURN 0; - END IF; - - ELSIF role COLLATE sys.database_default IN ( - 'serveradmin', - 'setupadmin', - 'processadmin', - 'diskadmin', - 'bulkadmin') THEN - RETURN 0; - - ELSE - RETURN NULL; - END IF; - - EXCEPTION WHEN OTHERS THEN - RETURN NULL; -END; -$$ LANGUAGE plpgsql STABLE; - --- sp_helpsrvrolemember -CREATE OR REPLACE PROCEDURE sys.sp_helpsrvrolemember("@srvrolename" sys.SYSNAME = NULL) AS -$$ -BEGIN - -- If server role is not specified, return info for all server roles - IF @srvrolename IS NULL - BEGIN - SELECT CAST(Ext1.rolname AS sys.SYSNAME) AS 'ServerRole', - CAST(Ext2.rolname AS sys.SYSNAME) AS 'MemberName', - CAST(CAST(Base2.oid AS INT) AS sys.VARBINARY(85)) AS 'MemberSID' - FROM pg_catalog.pg_auth_members AS Authmbr - INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid - INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.member - INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Base1.rolname = Ext1.rolname - INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Base2.rolname = Ext2.rolname - WHERE Ext1.type = 'R' AND Ext2.type != 'Z' - ORDER BY ServerRole, MemberName; - END - -- If a valid server role is specified, return its member info - -- If the role is a SQL server predefined role (i.e. serveradmin), - -- do not raise an error even if it does not exist - ELSE IF EXISTS (SELECT 1 - FROM sys.babelfish_authid_login_ext - WHERE (rolname = RTRIM(@srvrolename) - OR lower(rolname) = lower(RTRIM(@srvrolename))) - AND type = 'R') - OR lower(RTRIM(@srvrolename)) IN ( - 'serveradmin', 'setupadmin', 'processadmin', - 'diskadmin', 'bulkadmin') - BEGIN - SELECT CAST(Ext1.rolname AS sys.SYSNAME) AS 'ServerRole', - CAST(Ext2.rolname AS sys.SYSNAME) AS 'MemberName', - CAST(CAST(Base2.oid AS INT) AS sys.VARBINARY(85)) AS 'MemberSID' - FROM pg_catalog.pg_auth_members AS Authmbr - INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid - INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.member - INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Base1.rolname = Ext1.rolname - INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Base2.rolname = Ext2.rolname - WHERE Ext1.type = 'R' AND Ext2.type != 'Z' - AND (Ext1.rolname = RTRIM(@srvrolename) OR lower(Ext1.rolname) = lower(RTRIM(@srvrolename))) - ORDER BY ServerRole, MemberName; - END - -- If the specified server role is not valid - ELSE - RAISERROR('%s is not a known fixed role.', 16, 1, @srvrolename); -END; -$$ -LANGUAGE 'pltsql'; -GRANT EXECUTE ON PROCEDURE sys.sp_helpsrvrolemember TO PUBLIC; - --- SYSLOGINS -CREATE OR REPLACE VIEW sys.syslogins -AS SELECT -Base.sid AS sid, -CAST(9 AS SYS.TINYINT) AS status, -Base.create_date AS createdate, -Base.modify_date AS updatedate, -Base.create_date AS accdate, -CAST(0 AS INT) AS totcpu, -CAST(0 AS INT) AS totio, -CAST(0 AS INT) AS spacelimit, -CAST(0 AS INT) AS timelimit, -CAST(0 AS INT) AS resultlimit, -Base.name AS name, -Base.default_database_name AS dbname, -Base.default_language_name AS default_language_name, -CAST(Base.name AS SYS.NVARCHAR(128)) AS loginname, -CAST(NULL AS SYS.NVARCHAR(128)) AS password, -CAST(0 AS INT) AS denylogin, -CAST(1 AS INT) AS hasaccess, -CAST( - CASE - WHEN Base.type_desc = 'WINDOWS_LOGIN' OR Base.type_desc = 'WINDOWS_GROUP' THEN 1 - ELSE 0 - END -AS INT) AS isntname, -CAST( - CASE - WHEN Base.type_desc = 'WINDOWS_GROUP' THEN 1 - ELSE 0 - END - AS INT) AS isntgroup, -CAST( - CASE - WHEN Base.type_desc = 'WINDOWS_LOGIN' THEN 1 - ELSE 0 - END -AS INT) AS isntuser, -CAST( - CASE - WHEN is_srvrolemember('sysadmin', Base.name) = 1 THEN 1 - ELSE 0 - END -AS INT) AS sysadmin, -CAST( - CASE - WHEN is_srvrolemember('securityadmin', Base.name) = 1 THEN 1 - ELSE 0 - END -AS INT) AS securityadmin, -CAST(0 AS INT) AS serveradmin, -CAST(0 AS INT) AS setupadmin, -CAST(0 AS INT) AS processadmin, -CAST(0 AS INT) AS diskadmin, -CAST( - CASE - WHEN is_srvrolemember('dbcreator', Base.name) = 1 THEN 1 - ELSE 0 - END -AS INT) AS dbcreator, -CAST(0 AS INT) AS bulkadmin -FROM sys.server_principals AS Base -WHERE Base.type in ('S', 'U'); - -GRANT SELECT ON sys.syslogins TO PUBLIC; - CREATE OR REPLACE VIEW sys.configurations AS SELECT configuration_id, @@ -411,7 +136,6 @@ SELECT c.value_in_use AS value, END AS status FROM sys.configurations c LEFT JOIN sys.babelfish_configurations b ON c.configuration_id = b.configuration_id; GRANT SELECT ON sys.sysconfigures TO PUBLIC; - -- Assigning dbo role to the db_owner login DO $$ DECLARE @@ -1322,9 +1046,7 @@ BEGIN END IF; ELSIF EXISTS (SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE orig_username = role COLLATE sys.database_default) THEN - IF (((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = CURRENT_USER) = 'dbo' COLLATE sys.database_default) AND role COLLATE sys.database_default IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')) - THEN RETURN 1; - ELSIF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default) + IF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default) THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group ELSIF (is_windows_grp) THEN RETURN NULL; -- Return NULL if session is not a windows auth session but argument is a windows group @@ -1957,103 +1679,6 @@ BEGIN 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'); - -CREATE OR REPLACE PROCEDURE sys.sp_column_privileges( - "@table_name" sys.sysname, - "@table_owner" sys.sysname = '', - "@table_qualifier" sys.sysname = '', - "@column_name" sys.nvarchar(384) = '' -) -AS $$ -BEGIN - 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 (COALESCE(@table_owner, '') = '') - BEGIN - - IF EXISTS ( - SELECT * FROM sys.sp_column_privileges_view - WHERE LOWER(@table_name) = LOWER(table_name) and LOWER(SCHEMA_NAME()) = 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 LOWER(@table_name) = LOWER(table_name) - AND (LOWER(SCHEMA_NAME()) = LOWER(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE 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 LOWER(@table_name) = LOWER(table_name) - AND (LOWER('dbo')= LOWER(table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END - END - ELSE - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - COLUMN_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE - FROM sys.sp_column_privileges_view - WHERE LOWER(@table_name) = LOWER(table_name) - AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(table_owner) = LOWER(@table_owner)) - AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) - AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name)) - ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; - END -END; -$$ -LANGUAGE 'pltsql'; -GRANT EXECUTE ON PROCEDURE sys.sp_column_privileges TO PUBLIC; - 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 @@ -2080,56 +1705,57 @@ 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'; +WHERE t4.privilege_type = 'DELETE'; -CREATE OR REPLACE PROCEDURE sys.sp_table_privileges( - "@table_name" sys.nvarchar(384), - "@table_owner" sys.nvarchar(384) = '', - "@table_qualifier" sys.sysname = '', - "@fusepattern" sys.bit = 1 -) -AS $$ +CREATE OR REPLACE FUNCTION is_srvrolemember(role sys.SYSNAME, login sys.SYSNAME DEFAULT suser_name()) +RETURNS INTEGER AS +$$ +DECLARE has_role BOOLEAN; +DECLARE login_valid BOOLEAN; BEGIN + role := TRIM(trailing from LOWER(role)); + login := TRIM(trailing from LOWER(login)); - 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 + login_valid = (login = suser_name() COLLATE sys.database_default) OR + (EXISTS (SELECT name + FROM sys.server_principals + WHERE + LOWER(name) = login COLLATE sys.database_default + AND type = 'S')); + + IF NOT login_valid THEN + RETURN NULL; + + ELSIF role = 'public' COLLATE sys.database_default THEN + RETURN 1; - IF @fusepattern = 1 - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE FROM sys.sp_table_privileges_view - WHERE LOWER(TABLE_NAME) LIKE LOWER(@table_name) - AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) LIKE LOWER(@table_owner)) - ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; - END - ELSE - BEGIN - SELECT - TABLE_QUALIFIER, - TABLE_OWNER, - TABLE_NAME, - GRANTOR, - GRANTEE, - PRIVILEGE, - IS_GRANTABLE FROM sys.sp_table_privileges_view - WHERE LOWER(TABLE_NAME) = LOWER(@table_name) - AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) = LOWER(@table_owner)) - ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; - END + ELSIF role = 'sysadmin' COLLATE sys.database_default THEN + has_role = pg_has_role(login::TEXT, role::TEXT, 'MEMBER'); + IF has_role THEN + RETURN 1; + ELSE + RETURN 0; + END IF; -END; -$$ -LANGUAGE 'pltsql'; -GRANT EXECUTE ON PROCEDURE sys.sp_table_privileges TO PUBLIC; + ELSIF role COLLATE sys.database_default IN ( + 'serveradmin', + 'securityadmin', + 'setupadmin', + 'securityadmin', + 'processadmin', + 'dbcreator', + 'diskadmin', + 'bulkadmin') THEN + RETURN 0; + + ELSE + RETURN NULL; + END IF; + + EXCEPTION WHEN OTHERS THEN + RETURN NULL; +END; +$$ LANGUAGE plpgsql STABLE; CREATE OR REPLACE PROCEDURE sys.sp_helpuser("@name_in_db" sys.SYSNAME = NULL) AS $$ @@ -4434,210 +4060,6 @@ CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'sp_statistics_inte CALL sys.babelfish_drop_deprecated_object('function', 'sys', 'sp_pkeys_internal_deprecated_in_4_4_0'); --- DATABASE_PRINCIPALS -CREATE OR REPLACE VIEW sys.database_principals AS -SELECT -CAST(Ext.orig_username AS SYS.SYSNAME) AS name, -CAST(Base.oid AS INT) AS principal_id, -CAST(Ext.type AS CHAR(1)) as type, -CAST( - CASE - WHEN Ext.type = 'S' THEN 'SQL_USER' - WHEN Ext.type = 'R' THEN 'DATABASE_ROLE' - WHEN Ext.type = 'U' THEN 'WINDOWS_USER' - ELSE NULL - END - AS SYS.NVARCHAR(60)) AS type_desc, -CAST(Ext.default_schema_name AS SYS.SYSNAME) AS default_schema_name, -CAST(Ext.create_date AS SYS.DATETIME) AS create_date, -CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date, -CAST(Ext.owning_principal_id AS INT) AS owning_principal_id, -CAST(CAST(Base2.oid AS INT) AS SYS.VARBINARY(85)) AS SID, -CAST(Ext.is_fixed_role AS SYS.BIT) AS is_fixed_role, -CAST(Ext.authentication_type AS INT) AS authentication_type, -CAST(Ext.authentication_type_desc AS SYS.NVARCHAR(60)) AS authentication_type_desc, -CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name, -CAST(Ext.default_language_lcid AS INT) AS default_language_lcid, -CAST(Ext.allow_encrypted_value_modifications AS SYS.BIT) AS allow_encrypted_value_modifications -FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_user_ext AS Ext -ON Base.rolname = Ext.rolname -LEFT OUTER JOIN pg_catalog.pg_roles Base2 -ON Ext.login_name = Base2.rolname -WHERE Ext.database_name = DB_NAME() - AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter', 'guest') -- system users should always be visible - OR pg_has_role(Ext.rolname, 'MEMBER')) -- Current user should be able to see users it has permission of -UNION ALL -SELECT -CAST(name AS SYS.SYSNAME) AS name, -CAST(-1 AS INT) AS principal_id, -CAST(type AS CHAR(1)) as type, -CAST( - CASE - WHEN type = 'S' THEN 'SQL_USER' - WHEN type = 'R' THEN 'DATABASE_ROLE' - WHEN type = 'U' THEN 'WINDOWS_USER' - ELSE NULL - END - AS SYS.NVARCHAR(60)) AS type_desc, -CAST(NULL AS SYS.SYSNAME) AS default_schema_name, -CAST(NULL AS SYS.DATETIME) AS create_date, -CAST(NULL AS SYS.DATETIME) AS modify_date, -CAST(-1 AS INT) AS owning_principal_id, -CAST(CAST(0 AS INT) AS SYS.VARBINARY(85)) AS SID, -CAST(0 AS SYS.BIT) AS is_fixed_role, -CAST(-1 AS INT) AS authentication_type, -CAST(NULL AS SYS.NVARCHAR(60)) AS authentication_type_desc, -CAST(NULL AS SYS.SYSNAME) AS default_language_name, -CAST(-1 AS INT) AS default_language_lcid, -CAST(0 AS SYS.BIT) AS allow_encrypted_value_modifications -FROM (VALUES ('public', 'R'), ('sys', 'S'), ('INFORMATION_SCHEMA', 'S')) as dummy_principals(name, type); -GRANT SELECT ON sys.database_principals TO PUBLIC; - -CREATE OR REPLACE PROCEDURE sys.sp_helpdbfixedrole("@rolename" sys.SYSNAME = NULL) AS -$$ -BEGIN - -- Returns a list of the fixed database roles. - IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') - BEGIN - SELECT CAST(DbFixedRole as sys.SYSNAME) AS DbFixedRole, CAST(Description AS sys.nvarchar(70)) AS Description FROM ( - VALUES ('db_owner', 'DB Owners'), - ('db_accessadmin', 'DB Access Administrators'), - ('db_datareader', 'DB Data Reader'), - ('db_datawriter', 'DB Data Writer')) x(DbFixedRole, Description) - WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole; - END - ELSE IF LOWER(RTRIM(@rolename)) IN ( - 'db_securityadmin','db_ddladmin', 'db_backupoperator', - 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter') - BEGIN - -- Return an empty result set instead of raising an error - SELECT CAST(NULL AS sys.SYSNAME) AS DbFixedRole, CAST(NULL AS sys.nvarchar(70)) AS Description - WHERE 1=0; - END - ELSE - RAISERROR('''%s'' is not a known fixed role.', 16, 1, @rolename); -END -$$ -LANGUAGE 'pltsql'; -GRANT EXECUTE ON PROCEDURE sys.sp_helpdbfixedrole TO PUBLIC; - -CREATE OR REPLACE PROCEDURE sys.sp_helpuser("@name_in_db" sys.SYSNAME = NULL) AS -$$ -BEGIN - -- If security account is not specified, return info about all users - IF @name_in_db IS NULL - BEGIN - SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner' - WHEN Ext2.orig_username IS NULL THEN 'public' - ELSE Ext2.orig_username END - AS SYS.SYSNAME) AS 'RoleName', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default - ELSE LogExt.orig_loginname END - AS SYS.SYSNAME) AS 'LoginName', - CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName', - CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName', - CAST(Base1.oid AS INT) AS 'UserID', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT) - WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT) - ELSE CAST(Base3.oid AS INT) END - AS SYS.VARBINARY(85)) AS 'SID' - FROM sys.babelfish_authid_user_ext AS Ext1 - INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname - LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member - LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid - LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname - LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name - LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname - LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME() - LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner - WHERE Ext1.database_name = DB_NAME() - AND (Ext1.type != 'R' OR Ext1.type != 'A') - AND Ext1.orig_username != 'db_owner' - AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') - ORDER BY UserName, RoleName; - END - -- If the security account is the db fixed role - db_owner - ELSE IF @name_in_db = 'db_owner' - BEGIN - -- TODO: Need to change after we can add/drop members to/from db_owner - SELECT CAST('db_owner' AS SYS.SYSNAME) AS 'Role_name', - ROLE_ID('db_owner') AS 'Role_id', - CAST('dbo' AS SYS.SYSNAME) AS 'Users_in_role', - USER_ID('dbo') AS 'Userid'; - END - -- If the security account is a db role - ELSE IF EXISTS (SELECT 1 - FROM sys.babelfish_authid_user_ext - WHERE (orig_username = @name_in_db - OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db)) - AND database_name = DB_NAME() - AND type = 'R') - BEGIN - SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'Role_name', - CAST(Base1.oid AS INT) AS 'Role_id', - CAST(Ext2.orig_username AS SYS.SYSNAME) AS 'Users_in_role', - CAST(Base2.oid AS INT) AS 'Userid' - FROM sys.babelfish_authid_user_ext AS Ext2 - INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.rolname = Ext2.rolname - INNER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base2.oid = Authmbr.member - LEFT OUTER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid - LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext1 ON Base1.rolname = Ext1.rolname - WHERE Ext1.database_name = DB_NAME() - AND Ext2.database_name = DB_NAME() - AND Ext1.type = 'R' - AND Ext2.orig_username != 'db_owner' - AND Ext2.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') - AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) - ORDER BY Role_name, Users_in_role; - END - -- If the security account is a user - ELSE IF EXISTS (SELECT 1 - FROM sys.babelfish_authid_user_ext - WHERE (orig_username = @name_in_db - OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db)) - AND database_name = DB_NAME() - AND type != 'R') - BEGIN - SELECT DISTINCT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner' - WHEN Ext2.orig_username IS NULL THEN 'public' - ELSE Ext2.orig_username END - AS SYS.SYSNAME) AS 'RoleName', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default - ELSE LogExt.orig_loginname END - AS SYS.SYSNAME) AS 'LoginName', - CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName', - CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName', - CAST(Base1.oid AS INT) AS 'UserID', - CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT) - WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT) - ELSE CAST(Base3.oid AS INT) END - AS SYS.VARBINARY(85)) AS 'SID' - FROM sys.babelfish_authid_user_ext AS Ext1 - INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname - LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member - LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid - LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname - LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name - LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname - LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME() - LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner - WHERE Ext1.database_name = DB_NAME() - AND (Ext1.type != 'R' OR Ext1.type != 'A') - AND Ext1.orig_username != 'db_owner' - AND Ext1.orig_username NOT IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter') - AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) - ORDER BY UserName, RoleName; - END - -- If the security account is not valid - ELSE - RAISERROR ( 'The name supplied (%s) is not a user, role, or aliased login.', 16, 1, @name_in_db); -END; -$$ -LANGUAGE 'pltsql'; -GRANT EXECUTE on PROCEDURE sys.sp_helpuser TO PUBLIC; - CREATE OR REPLACE VIEW sys.sp_sproc_columns_view AS SELECT diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql index a24b5aa5749..d59dee6f21c 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql @@ -12,6 +12,770 @@ SELECT set_config('search_path', 'sys, '||current_setting('search_path'), false) */ +CREATE OR REPLACE PROCEDURE sys.create_db_roles_during_upgrade() +LANGUAGE C +AS 'babelfishpg_tsql', 'create_db_roles_during_upgrade'; + +CALL sys.create_db_roles_during_upgrade(); + +DROP PROCEDURE sys.create_db_roles_during_upgrade(); + +DO +LANGUAGE plpgsql +$$ +DECLARE + existing_server_roles TEXT; +BEGIN + SELECT STRING_AGG(rolname::text, ', ') + INTO existing_server_roles FROM pg_catalog.pg_roles + WHERE rolname IN ('securityadmin', 'dbcreator'); + + IF existing_server_roles IS NOT NULL THEN + RAISE EXCEPTION 'The following role(s) already exist(s): %', existing_server_roles; + ELSE + EXECUTE format('CREATE ROLE securityadmin CREATEROLE INHERIT PASSWORD NULL'); + EXECUTE format('GRANT securityadmin TO bbf_role_admin WITH ADMIN TRUE'); + CALL sys.babel_initialize_logins('securityadmin'); + EXECUTE format('CREATE ROLE dbcreator CREATEDB INHERIT PASSWORD NULL'); + EXECUTE format('GRANT dbcreator TO bbf_role_admin WITH ADMIN TRUE'); + CALL sys.babel_initialize_logins('dbcreator'); + END IF; +END; +$$; + +CREATE OR REPLACE FUNCTION sys.bbf_is_member_of_role_nosuper(OID, OID) +RETURNS BOOLEAN AS 'babelfishpg_tsql', 'bbf_is_member_of_role_nosuper' +LANGUAGE C STABLE STRICT PARALLEL SAFE; + +-- SERVER_PRINCIPALS +CREATE OR REPLACE VIEW sys.server_principals +AS SELECT +CAST(Ext.orig_loginname AS sys.SYSNAME) AS name, +CAST(Base.oid As INT) AS principal_id, +CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, +CAST(Ext.type AS CHAR(1)) as type, +CAST( + CASE + WHEN Ext.type = 'S' THEN 'SQL_LOGIN' + WHEN Ext.type = 'R' THEN 'SERVER_ROLE' + WHEN Ext.type = 'U' THEN 'WINDOWS_LOGIN' + ELSE NULL + END + AS NVARCHAR(60)) AS type_desc, +CAST(Ext.is_disabled AS INT) AS is_disabled, +CAST(Ext.create_date AS SYS.DATETIME) AS create_date, +CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date, +CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.default_database_name END AS SYS.SYSNAME) AS default_database_name, +CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name, +CAST(CASE WHEN Ext.type = 'R' THEN NULL ELSE Ext.credential_id END AS INT) AS credential_id, +CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.owning_principal_id END AS INT) AS owning_principal_id, +CAST(CASE WHEN Ext.type = 'R' THEN 1 ELSE Ext.is_fixed_role END AS sys.BIT) AS is_fixed_role +FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname +WHERE (pg_has_role(suser_id(), 'sysadmin'::TEXT, 'MEMBER') + OR pg_has_role(suser_id(), 'securityadmin'::TEXT, 'MEMBER') + OR Ext.orig_loginname = suser_name() + OR Ext.orig_loginname = (SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = CURRENT_DATABASE()) COLLATE sys.database_default + OR Ext.type = 'R') + AND Ext.type != 'Z' +UNION ALL +SELECT +CAST('public' AS SYS.SYSNAME) AS name, +CAST(-1 AS INT) AS principal_id, +CAST(CAST(0 as INT) as sys.varbinary(85)) AS sid, +CAST('R' AS CHAR(1)) as type, +CAST('SERVER_ROLE' AS NVARCHAR(60)) AS type_desc, +CAST(0 AS INT) AS is_disabled, +CAST(NULL AS SYS.DATETIME) AS create_date, +CAST(NULL AS SYS.DATETIME) AS modify_date, +CAST(NULL AS SYS.SYSNAME) AS default_database_name, +CAST(NULL AS SYS.SYSNAME) AS default_language_name, +CAST(NULL AS INT) AS credential_id, +CAST(1 AS INT) AS owning_principal_id, +CAST(0 AS sys.BIT) AS is_fixed_role; + +GRANT SELECT ON sys.server_principals TO PUBLIC; + +-- login_token +CREATE OR REPLACE VIEW sys.login_token +AS SELECT +CAST(Base.oid As INT) AS principal_id, +CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, +CAST(Ext.orig_loginname AS sys.nvarchar(128)) AS name, +CAST(CASE +WHEN Ext.type = 'U' THEN 'WINDOWS LOGIN' +ELSE 'SQL LOGIN' END AS SYS.NVARCHAR(128)) AS TYPE, +CAST('GRANT OR DENY' as sys.nvarchar(128)) as usage +FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname +WHERE Ext.orig_loginname = sys.suser_name() +AND Ext.type in ('S','U') +UNION ALL +SELECT +CAST(Base.oid As INT) AS principal_id, +CAST(CAST(Base.oid as INT) as sys.varbinary(85)) AS sid, +CAST(Ext.orig_loginname AS sys.nvarchar(128)) AS name, +CAST('SERVER ROLE' AS sys.nvarchar(128)) AS type, +CAST ('GRANT OR DENY' as sys.nvarchar(128)) as usage +FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_login_ext AS Ext ON Base.rolname = Ext.rolname +WHERE Ext.type = 'R' +AND bbf_is_member_of_role_nosuper(sys.suser_id(), Base.oid); + +GRANT SELECT ON sys.login_token TO PUBLIC; + +CREATE OR REPLACE FUNCTION is_srvrolemember(role sys.SYSNAME, login sys.SYSNAME DEFAULT suser_name()) +RETURNS INTEGER AS +$$ +DECLARE has_role BOOLEAN; +DECLARE login_valid BOOLEAN; +BEGIN + role := TRIM(trailing from LOWER(role)); + login := TRIM(trailing from LOWER(login)); + + login_valid = (login = suser_name() COLLATE sys.database_default) OR + (EXISTS (SELECT name + FROM sys.server_principals + WHERE + LOWER(name) = login COLLATE sys.database_default + AND type IN ('S', 'R'))); + + IF NOT login_valid THEN + RETURN NULL; + + ELSIF role = 'public' COLLATE sys.database_default THEN + RETURN 1; + + ELSIF role COLLATE sys.database_default IN ('sysadmin', 'securityadmin', 'dbcreator') THEN + has_role = (pg_has_role(login::TEXT, role::TEXT, 'MEMBER') + OR ((login COLLATE sys.database_default NOT IN ('sysadmin', 'securityadmin', 'dbcreator')) + AND pg_has_role(login::TEXT, 'sysadmin'::TEXT, 'MEMBER'))); + IF has_role THEN + RETURN 1; + ELSE + RETURN 0; + END IF; + + ELSIF role COLLATE sys.database_default IN ( + 'serveradmin', + 'setupadmin', + 'processadmin', + 'diskadmin', + 'bulkadmin') THEN + RETURN 0; + + ELSE + RETURN NULL; + END IF; + + EXCEPTION WHEN OTHERS THEN + RETURN NULL; +END; +$$ LANGUAGE plpgsql STABLE; + +-- sp_helpsrvrolemember +CREATE OR REPLACE PROCEDURE sys.sp_helpsrvrolemember("@srvrolename" sys.SYSNAME = NULL) AS +$$ +BEGIN + -- If server role is not specified, return info for all server roles + IF @srvrolename IS NULL + BEGIN + SELECT CAST(Ext1.rolname AS sys.SYSNAME) AS 'ServerRole', + CAST(Ext2.rolname AS sys.SYSNAME) AS 'MemberName', + CAST(CAST(Base2.oid AS INT) AS sys.VARBINARY(85)) AS 'MemberSID' + FROM pg_catalog.pg_auth_members AS Authmbr + INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid + INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.member + INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Base1.rolname = Ext1.rolname + INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Base2.rolname = Ext2.rolname + WHERE Ext1.type = 'R' AND Ext2.type != 'Z' + ORDER BY ServerRole, MemberName; + END + -- If a valid server role is specified, return its member info + -- If the role is a SQL server predefined role (i.e. serveradmin), + -- do not raise an error even if it does not exist + ELSE IF EXISTS (SELECT 1 + FROM sys.babelfish_authid_login_ext + WHERE (rolname = RTRIM(@srvrolename) + OR lower(rolname) = lower(RTRIM(@srvrolename))) + AND type = 'R') + OR lower(RTRIM(@srvrolename)) IN ( + 'serveradmin', 'setupadmin', 'processadmin', + 'diskadmin', 'bulkadmin') + BEGIN + SELECT CAST(Ext1.rolname AS sys.SYSNAME) AS 'ServerRole', + CAST(Ext2.rolname AS sys.SYSNAME) AS 'MemberName', + CAST(CAST(Base2.oid AS INT) AS sys.VARBINARY(85)) AS 'MemberSID' + FROM pg_catalog.pg_auth_members AS Authmbr + INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid + INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.member + INNER JOIN sys.babelfish_authid_login_ext AS Ext1 ON Base1.rolname = Ext1.rolname + INNER JOIN sys.babelfish_authid_login_ext AS Ext2 ON Base2.rolname = Ext2.rolname + WHERE Ext1.type = 'R' AND Ext2.type != 'Z' + AND (Ext1.rolname = RTRIM(@srvrolename) OR lower(Ext1.rolname) = lower(RTRIM(@srvrolename))) + ORDER BY ServerRole, MemberName; + END + -- If the specified server role is not valid + ELSE + RAISERROR('%s is not a known fixed role.', 16, 1, @srvrolename); +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_helpsrvrolemember TO PUBLIC; + +-- SYSLOGINS +CREATE OR REPLACE VIEW sys.syslogins +AS SELECT +Base.sid AS sid, +CAST(9 AS SYS.TINYINT) AS status, +Base.create_date AS createdate, +Base.modify_date AS updatedate, +Base.create_date AS accdate, +CAST(0 AS INT) AS totcpu, +CAST(0 AS INT) AS totio, +CAST(0 AS INT) AS spacelimit, +CAST(0 AS INT) AS timelimit, +CAST(0 AS INT) AS resultlimit, +Base.name AS name, +Base.default_database_name AS dbname, +Base.default_language_name AS default_language_name, +CAST(Base.name AS SYS.NVARCHAR(128)) AS loginname, +CAST(NULL AS SYS.NVARCHAR(128)) AS password, +CAST(0 AS INT) AS denylogin, +CAST(1 AS INT) AS hasaccess, +CAST( + CASE + WHEN Base.type_desc = 'WINDOWS_LOGIN' OR Base.type_desc = 'WINDOWS_GROUP' THEN 1 + ELSE 0 + END +AS INT) AS isntname, +CAST( + CASE + WHEN Base.type_desc = 'WINDOWS_GROUP' THEN 1 + ELSE 0 + END + AS INT) AS isntgroup, +CAST( + CASE + WHEN Base.type_desc = 'WINDOWS_LOGIN' THEN 1 + ELSE 0 + END +AS INT) AS isntuser, +CAST( + CASE + WHEN is_srvrolemember('sysadmin', Base.name) = 1 THEN 1 + ELSE 0 + END +AS INT) AS sysadmin, +CAST( + CASE + WHEN is_srvrolemember('securityadmin', Base.name) = 1 THEN 1 + ELSE 0 + END +AS INT) AS securityadmin, +CAST(0 AS INT) AS serveradmin, +CAST(0 AS INT) AS setupadmin, +CAST(0 AS INT) AS processadmin, +CAST(0 AS INT) AS diskadmin, +CAST( + CASE + WHEN is_srvrolemember('dbcreator', Base.name) = 1 THEN 1 + ELSE 0 + END +AS INT) AS dbcreator, +CAST(0 AS INT) AS bulkadmin +FROM sys.server_principals AS Base +WHERE Base.type in ('S', 'U'); + +GRANT SELECT ON sys.syslogins TO PUBLIC; + +CREATE OR REPLACE FUNCTION sys.is_member(IN role sys.SYSNAME) +RETURNS INT AS +$$ +DECLARE + is_windows_grp boolean := (CHARINDEX('\', role) != 0); +BEGIN + -- Always return 1 for 'public' + IF (role = 'public' COLLATE sys.database_default ) + THEN RETURN 1; + END IF; + + IF EXISTS (SELECT orig_loginname FROM sys.babelfish_authid_login_ext WHERE orig_loginname = role COLLATE sys.database_default AND type != 'S') -- do not consider sql logins + THEN + IF ((EXISTS (SELECT name FROM sys.login_token WHERE name = role COLLATE sys.database_default AND type IN ('SERVER ROLE', 'SQL LOGIN'))) OR is_windows_grp) -- do not consider sql logins, server roles + THEN RETURN NULL; -- Also return NULL if session is not a windows auth session but argument is a windows group + ELSIF EXISTS (SELECT name FROM sys.login_token WHERE name = role COLLATE sys.database_default AND type NOT IN ('SERVER ROLE', 'SQL LOGIN')) + THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group + ELSE RETURN 0; -- Return 0 if current session user is not a member of role or windows group + END IF; + ELSIF EXISTS (SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE orig_username = role COLLATE sys.database_default) + THEN + IF (((SELECT orig_username FROM sys.babelfish_authid_user_ext WHERE rolname = CURRENT_USER) = 'dbo' COLLATE sys.database_default) AND role COLLATE sys.database_default IN ('db_owner', 'db_accessadmin', 'db_datareader', 'db_datawriter')) + THEN RETURN 1; + ELSIF EXISTS (SELECT name FROM sys.user_token WHERE name = role COLLATE sys.database_default) + THEN RETURN 1; -- Return 1 if current session user is a member of role or windows group + ELSIF (is_windows_grp) + THEN RETURN NULL; -- Return NULL if session is not a windows auth session but argument is a windows group + ELSE RETURN 0; -- Return 0 if current session user is not a member of role or windows group + END IF; + ELSE RETURN NULL; -- Return NULL if role/group does not exist + END IF; +END; +$$ +LANGUAGE plpgsql STRICT STABLE; + +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 +CAST(TABLE_QUALIFIER AS sys.sysname) COLLATE sys.database_default AS TABLE_QUALIFIER, +CAST(TABLE_OWNER AS sys.sysname) AS TABLE_OWNER, +CAST(TABLE_NAME AS sys.sysname) COLLATE sys.database_default AS TABLE_NAME, +CAST(GRANTOR AS sys.sysname) AS GRANTOR, +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'; + +CREATE OR REPLACE PROCEDURE sys.sp_table_privileges( + "@table_name" sys.nvarchar(384), + "@table_owner" sys.nvarchar(384) = '', + "@table_qualifier" sys.sysname = '', + "@fusepattern" sys.bit = 1 +) +AS $$ +BEGIN + + 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 + BEGIN + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE FROM sys.sp_table_privileges_view + WHERE LOWER(TABLE_NAME) LIKE LOWER(@table_name) + AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) LIKE LOWER(@table_owner)) + ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; + END + ELSE + BEGIN + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE FROM sys.sp_table_privileges_view + WHERE LOWER(TABLE_NAME) = LOWER(@table_name) + AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) = LOWER(@table_owner)) + ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; + END + +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_table_privileges TO PUBLIC; + + +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'); + +CREATE OR REPLACE PROCEDURE sys.sp_column_privileges( + "@table_name" sys.sysname, + "@table_owner" sys.sysname = '', + "@table_qualifier" sys.sysname = '', + "@column_name" sys.nvarchar(384) = '' +) +AS $$ +BEGIN + 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 (COALESCE(@table_owner, '') = '') + BEGIN + + IF EXISTS ( + SELECT * FROM sys.sp_column_privileges_view + WHERE LOWER(@table_name) = LOWER(table_name) and LOWER(SCHEMA_NAME()) = 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 LOWER(@table_name) = LOWER(table_name) + AND (LOWER(SCHEMA_NAME()) = LOWER(table_owner)) + AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) + AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE 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 LOWER(@table_name) = LOWER(table_name) + AND (LOWER('dbo')= LOWER(table_owner)) + AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) + AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name)) + ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; + END + END + ELSE + BEGIN + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + COLUMN_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE + FROM sys.sp_column_privileges_view + WHERE LOWER(@table_name) = LOWER(table_name) + AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(table_owner) = LOWER(@table_owner)) + AND ((SELECT COALESCE(@table_qualifier,'')) = '' OR LOWER(table_qualifier) = LOWER(@table_qualifier)) + AND ((SELECT COALESCE(@column_name,'')) = '' OR LOWER(column_name) LIKE LOWER(@column_name)) + ORDER BY table_qualifier, table_owner, table_name, column_name, privilege, grantee; + END +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_column_privileges TO PUBLIC; + +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 +CAST(TABLE_QUALIFIER AS sys.sysname) COLLATE sys.database_default AS TABLE_QUALIFIER, +CAST(TABLE_OWNER AS sys.sysname) AS TABLE_OWNER, +CAST(TABLE_NAME AS sys.sysname) COLLATE sys.database_default AS TABLE_NAME, +CAST(GRANTOR AS sys.sysname) AS GRANTOR, +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'; + +CREATE OR REPLACE PROCEDURE sys.sp_table_privileges( + "@table_name" sys.nvarchar(384), + "@table_owner" sys.nvarchar(384) = '', + "@table_qualifier" sys.sysname = '', + "@fusepattern" sys.bit = 1 +) +AS $$ +BEGIN + + 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 + BEGIN + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE FROM sys.sp_table_privileges_view + WHERE LOWER(TABLE_NAME) LIKE LOWER(@table_name) + AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) LIKE LOWER(@table_owner)) + ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; + END + ELSE + BEGIN + SELECT + TABLE_QUALIFIER, + TABLE_OWNER, + TABLE_NAME, + GRANTOR, + GRANTEE, + PRIVILEGE, + IS_GRANTABLE FROM sys.sp_table_privileges_view + WHERE LOWER(TABLE_NAME) = LOWER(@table_name) + AND ((SELECT COALESCE(@table_owner,'')) = '' OR LOWER(TABLE_OWNER) = LOWER(@table_owner)) + ORDER BY table_qualifier, table_owner, table_name, privilege, grantee; + END + +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_table_privileges TO PUBLIC; + + +-- DATABASE_PRINCIPALS +CREATE OR REPLACE VIEW sys.database_principals AS +SELECT +CAST(Ext.orig_username AS SYS.SYSNAME) AS name, +CAST(Base.oid AS INT) AS principal_id, +CAST(Ext.type AS CHAR(1)) as type, +CAST( + CASE + WHEN Ext.type = 'S' THEN 'SQL_USER' + WHEN Ext.type = 'R' THEN 'DATABASE_ROLE' + WHEN Ext.type = 'U' THEN 'WINDOWS_USER' + ELSE NULL + END + AS SYS.NVARCHAR(60)) AS type_desc, +CAST(Ext.default_schema_name AS SYS.SYSNAME) AS default_schema_name, +CAST(Ext.create_date AS SYS.DATETIME) AS create_date, +CAST(Ext.modify_date AS SYS.DATETIME) AS modify_date, +CAST(Ext.owning_principal_id AS INT) AS owning_principal_id, +CAST(CAST(Base2.oid AS INT) AS SYS.VARBINARY(85)) AS SID, +CAST(Ext.is_fixed_role AS SYS.BIT) AS is_fixed_role, +CAST(Ext.authentication_type AS INT) AS authentication_type, +CAST(Ext.authentication_type_desc AS SYS.NVARCHAR(60)) AS authentication_type_desc, +CAST(Ext.default_language_name AS SYS.SYSNAME) AS default_language_name, +CAST(Ext.default_language_lcid AS INT) AS default_language_lcid, +CAST(Ext.allow_encrypted_value_modifications AS SYS.BIT) AS allow_encrypted_value_modifications +FROM pg_catalog.pg_roles AS Base INNER JOIN sys.babelfish_authid_user_ext AS Ext +ON Base.rolname = Ext.rolname +LEFT OUTER JOIN pg_catalog.pg_roles Base2 +ON Ext.login_name = Base2.rolname +WHERE Ext.database_name = DB_NAME() + AND (Ext.orig_username IN ('dbo', 'db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter', 'guest') -- system users should always be visible + OR pg_has_role(Ext.rolname, 'MEMBER')) -- Current user should be able to see users it has permission of +UNION ALL +SELECT +CAST(name AS SYS.SYSNAME) AS name, +CAST(-1 AS INT) AS principal_id, +CAST(type AS CHAR(1)) as type, +CAST( + CASE + WHEN type = 'S' THEN 'SQL_USER' + WHEN type = 'R' THEN 'DATABASE_ROLE' + WHEN type = 'U' THEN 'WINDOWS_USER' + ELSE NULL + END + AS SYS.NVARCHAR(60)) AS type_desc, +CAST(NULL AS SYS.SYSNAME) AS default_schema_name, +CAST(NULL AS SYS.DATETIME) AS create_date, +CAST(NULL AS SYS.DATETIME) AS modify_date, +CAST(-1 AS INT) AS owning_principal_id, +CAST(CAST(0 AS INT) AS SYS.VARBINARY(85)) AS SID, +CAST(0 AS SYS.BIT) AS is_fixed_role, +CAST(-1 AS INT) AS authentication_type, +CAST(NULL AS SYS.NVARCHAR(60)) AS authentication_type_desc, +CAST(NULL AS SYS.SYSNAME) AS default_language_name, +CAST(-1 AS INT) AS default_language_lcid, +CAST(0 AS SYS.BIT) AS allow_encrypted_value_modifications +FROM (VALUES ('public', 'R'), ('sys', 'S'), ('INFORMATION_SCHEMA', 'S')) as dummy_principals(name, type); +GRANT SELECT ON sys.database_principals TO PUBLIC; + +CREATE OR REPLACE PROCEDURE sys.sp_helpdbfixedrole("@rolename" sys.SYSNAME = NULL) AS +$$ +BEGIN + -- Returns a list of the fixed database roles. + IF LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) IN ('db_owner', 'db_accessadmin', 'db_securityadmin', 'db_datareader', 'db_datawriter') + BEGIN + SELECT CAST(DbFixedRole as sys.SYSNAME) AS DbFixedRole, CAST(Description AS sys.nvarchar(70)) AS Description FROM ( + VALUES ('db_owner', 'DB Owners'), + ('db_accessadmin', 'DB Access Administrators'), + ('db_securityadmin', 'DB Security Administrators'), + ('db_datareader', 'DB Data Reader'), + ('db_datawriter', 'DB Data Writer')) x(DbFixedRole, Description) + WHERE LOWER(RTRIM(@rolename)) IS NULL OR LOWER(RTRIM(@rolename)) = DbFixedRole; + END + ELSE IF LOWER(RTRIM(@rolename)) IN ( + 'db_ddladmin', 'db_backupoperator', + 'db_denydatareader', 'db_denydatawriter') + BEGIN + -- Return an empty result set instead of raising an error + SELECT CAST(NULL AS sys.SYSNAME) AS DbFixedRole, CAST(NULL AS sys.nvarchar(70)) AS Description + WHERE 1=0; + END + ELSE + RAISERROR('''%s'' is not a known fixed role.', 16, 1, @rolename); +END +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE ON PROCEDURE sys.sp_helpdbfixedrole TO PUBLIC; + +CREATE OR REPLACE PROCEDURE sys.sp_helpuser("@name_in_db" sys.SYSNAME = NULL) AS +$$ +BEGIN + -- If security account is not specified, return info about all users + IF @name_in_db IS NULL + BEGIN + SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner' + WHEN Ext2.orig_username IS NULL THEN 'public' + ELSE Ext2.orig_username END + AS SYS.SYSNAME) AS 'RoleName', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default + ELSE LogExt.orig_loginname END + AS SYS.SYSNAME) AS 'LoginName', + CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName', + CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName', + CAST(Base1.oid AS INT) AS 'UserID', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT) + WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT) + ELSE CAST(Base3.oid AS INT) END + AS SYS.VARBINARY(85)) AS 'SID' + FROM sys.babelfish_authid_user_ext AS Ext1 + INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname + LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member + LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid + LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname + LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name + LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname + LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME() + LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner + WHERE Ext1.database_name = DB_NAME() + AND (Ext1.type != 'R' OR Ext1.type != 'A') + AND Ext1.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') + ORDER BY UserName, RoleName; + END + -- If the security account is the db fixed role - db_owner + ELSE IF @name_in_db = 'db_owner' + BEGIN + -- TODO: Need to change after we can add/drop members to/from db_owner + SELECT CAST('db_owner' AS SYS.SYSNAME) AS 'Role_name', + ROLE_ID('db_owner') AS 'Role_id', + CAST('dbo' AS SYS.SYSNAME) AS 'Users_in_role', + USER_ID('dbo') AS 'Userid'; + END + -- If the security account is a db role + ELSE IF EXISTS (SELECT 1 + FROM sys.babelfish_authid_user_ext + WHERE (orig_username = @name_in_db + OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db)) + AND database_name = DB_NAME() + AND type = 'R') + BEGIN + SELECT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'Role_name', + CAST(Base1.oid AS INT) AS 'Role_id', + CAST(Ext2.orig_username AS SYS.SYSNAME) AS 'Users_in_role', + CAST(Base2.oid AS INT) AS 'Userid' + FROM sys.babelfish_authid_user_ext AS Ext2 + INNER JOIN pg_catalog.pg_roles AS Base2 ON Base2.rolname = Ext2.rolname + INNER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base2.oid = Authmbr.member + LEFT OUTER JOIN pg_catalog.pg_roles AS Base1 ON Base1.oid = Authmbr.roleid + LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext1 ON Base1.rolname = Ext1.rolname + WHERE Ext1.database_name = DB_NAME() + AND Ext2.database_name = DB_NAME() + AND Ext1.type = 'R' + AND Ext2.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') + AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) + ORDER BY Role_name, Users_in_role; + END + -- If the security account is a user + ELSE IF EXISTS (SELECT 1 + FROM sys.babelfish_authid_user_ext + WHERE (orig_username = @name_in_db + OR pg_catalog.lower(orig_username) = pg_catalog.lower(@name_in_db)) + AND database_name = DB_NAME() + AND type != 'R') + BEGIN + SELECT DISTINCT CAST(Ext1.orig_username AS SYS.SYSNAME) AS 'UserName', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN 'db_owner' + WHEN Ext2.orig_username IS NULL THEN 'public' + ELSE Ext2.orig_username END + AS SYS.SYSNAME) AS 'RoleName', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN Base4.rolname COLLATE database_default + ELSE LogExt.orig_loginname END + AS SYS.SYSNAME) AS 'LoginName', + CAST(LogExt.default_database_name AS SYS.SYSNAME) AS 'DefDBName', + CAST(Ext1.default_schema_name AS SYS.SYSNAME) AS 'DefSchemaName', + CAST(Base1.oid AS INT) AS 'UserID', + CAST(CASE WHEN Ext1.orig_username = 'dbo' THEN CAST(Base4.oid AS INT) + WHEN Ext1.orig_username = 'guest' THEN CAST(0 AS INT) + ELSE CAST(Base3.oid AS INT) END + AS SYS.VARBINARY(85)) AS 'SID' + FROM sys.babelfish_authid_user_ext AS Ext1 + INNER JOIN pg_catalog.pg_roles AS Base1 ON Base1.rolname = Ext1.rolname + LEFT OUTER JOIN pg_catalog.pg_auth_members AS Authmbr ON Base1.oid = Authmbr.member + LEFT OUTER JOIN pg_catalog.pg_roles AS Base2 ON Base2.oid = Authmbr.roleid + LEFT OUTER JOIN sys.babelfish_authid_user_ext AS Ext2 ON Base2.rolname = Ext2.rolname + LEFT OUTER JOIN sys.babelfish_authid_login_ext As LogExt ON LogExt.rolname = Ext1.login_name + LEFT OUTER JOIN pg_catalog.pg_roles AS Base3 ON Base3.rolname = LogExt.rolname + LEFT OUTER JOIN sys.babelfish_sysdatabases AS Bsdb ON Bsdb.name = DB_NAME() + LEFT OUTER JOIN pg_catalog.pg_roles AS Base4 ON Base4.rolname = Bsdb.owner + WHERE Ext1.database_name = DB_NAME() + AND (Ext1.type != 'R' OR Ext1.type != 'A') + AND Ext1.orig_username NOT IN ('db_owner', 'db_securityadmin', 'db_accessadmin', 'db_datareader', 'db_datawriter') + AND (Ext1.orig_username = @name_in_db OR pg_catalog.lower(Ext1.orig_username) = pg_catalog.lower(@name_in_db)) + ORDER BY UserName, RoleName; + END + -- If the security account is not valid + ELSE + RAISERROR ( 'The name supplied (%s) is not a user, role, or aliased login.', 16, 1, @name_in_db); +END; +$$ +LANGUAGE 'pltsql'; +GRANT EXECUTE on PROCEDURE sys.sp_helpuser TO PUBLIC; + -- After upgrade, always run analyze for all babelfish catalogs. CALL sys.analyze_babelfish_catalogs(); diff --git a/contrib/babelfishpg_tsql/src/catalog.h b/contrib/babelfishpg_tsql/src/catalog.h index 5e2ba021b0b..111583dd2df 100644 --- a/contrib/babelfishpg_tsql/src/catalog.h +++ b/contrib/babelfishpg_tsql/src/catalog.h @@ -148,7 +148,7 @@ extern Oid bbf_authid_user_ext_idx_oid; #define BBF_ROLE 1 #define BBF_USER 2 -const int get_db_principal_kind(Oid role_oid, const char *db_name); +const int get_db_principal_kind(Oid role_oid, const char *db_name); extern Oid get_authid_user_ext_oid(void); extern Oid get_authid_user_ext_idx_oid(void); extern char *get_authid_user_ext_original_name(const char *physical_role_name, const char *db_name); diff --git a/contrib/babelfishpg_tsql/src/dbcmds.c b/contrib/babelfishpg_tsql/src/dbcmds.c index 69a2d7fe9ee..66f6564879c 100644 --- a/contrib/babelfishpg_tsql/src/dbcmds.c +++ b/contrib/babelfishpg_tsql/src/dbcmds.c @@ -87,6 +87,7 @@ gen_createdb_subcmds(const char *dbname, const char *owner) const char *dbo; const char *db_owner; const char *db_accessadmin; + const char *db_securityadmin; const char *guest; const char *guest_schema; Oid owner_oid; @@ -98,6 +99,7 @@ gen_createdb_subcmds(const char *dbname, const char *owner) dbo = get_dbo_role_name(dbname); db_owner = get_db_owner_name(dbname); db_accessadmin = get_db_accessadmin_role_name(dbname); + db_securityadmin = get_db_securityadmin_role_name(dbname); guest = get_guest_role_name(dbname); guest_schema = get_guest_schema_name(dbname); owner_oid = get_role_oid(owner, true); @@ -119,9 +121,14 @@ gen_createdb_subcmds(const char *dbname, const char *owner) if (!owner_is_sa) appendStringInfo(&query, "GRANT dummy TO dummy; "); - /* create db_accessadmin for database */ appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); + + /* create db_accessadmin for database */ + appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); + appendStringInfo(&query, "GRANT CREATE ON DATABASE dummy TO dummy; "); + + /* create db_securityadmin */ appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); appendStringInfo(&query, "GRANT CREATE ON DATABASE dummy TO dummy; "); @@ -146,13 +153,13 @@ gen_createdb_subcmds(const char *dbname, const char *owner) if (guest) { if (!owner_is_sa) - expected_stmt_num = list_length(logins) > 0 ? 14 : 13; + expected_stmt_num = list_length(logins) > 0 ? 16 : 15; else - expected_stmt_num = list_length(logins) > 0 ? 13 : 12; + expected_stmt_num = list_length(logins) > 0 ? 15 : 14; } else { - expected_stmt_num = 10; + expected_stmt_num = 12; if (!owner_is_sa) expected_stmt_num++; @@ -194,6 +201,12 @@ gen_createdb_subcmds(const char *dbname, const char *owner) stmt = parsetree_nth_stmt(res, i++); update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_accessadmin, NULL); + stmt = parsetree_nth_stmt(res, i++); + update_CreateRoleStmt(stmt, db_securityadmin, db_owner, NULL); + + stmt = parsetree_nth_stmt(res, i++); + update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_securityadmin, NULL); + if (guest) { stmt = parsetree_nth_stmt(res, i++); @@ -221,6 +234,14 @@ gen_createdb_subcmds(const char *dbname, const char *owner) update_CreateSchemaStmt(stmt, guest_schema, guest); } + pfree((char *) schema); + pfree((char *) dbo); + pfree((char *) db_owner); + pfree((char *) db_accessadmin); + pfree((char *) db_securityadmin); + pfree((char *) guest); + pfree((char *) guest_schema); + return res; } @@ -230,6 +251,7 @@ add_fixed_user_roles_to_bbf_authid_user_ext(const char *dbname) const char *dbo; const char *db_owner; const char *db_accessadmin; + const char *db_securityadmin; const char *db_datareader; const char *db_datawriter; const char *guest; @@ -237,6 +259,7 @@ add_fixed_user_roles_to_bbf_authid_user_ext(const char *dbname) dbo = get_dbo_role_name(dbname); db_owner = get_db_owner_name(dbname); db_accessadmin = get_db_accessadmin_role_name(dbname); + db_securityadmin = get_db_securityadmin_role_name(dbname); guest = get_guest_role_name(dbname); db_datareader = get_db_datareader_name(dbname); db_datawriter = get_db_datawriter_name(dbname); @@ -244,8 +267,9 @@ add_fixed_user_roles_to_bbf_authid_user_ext(const char *dbname) add_to_bbf_authid_user_ext(dbo, DBO, dbname, DBO, NULL, false, true, false); add_to_bbf_authid_user_ext(db_owner, DB_OWNER, dbname, NULL, NULL, true, true, false); add_to_bbf_authid_user_ext(db_accessadmin, DB_ACCESSADMIN, dbname, NULL, NULL, true, true, false); - add_to_bbf_authid_user_ext(db_datareader, DB_DATAREADER, dbname, NULL, NULL, true, true, false); - add_to_bbf_authid_user_ext(db_datawriter, DB_DATAWRITER, dbname, NULL, NULL, true, true, false); + add_to_bbf_authid_user_ext(db_securityadmin, DB_SECURITYADMIN, dbname, NULL, NULL, true, false, false); + add_to_bbf_authid_user_ext(db_datareader, DB_DATAREADER, dbname, NULL, NULL, true, false, false); + add_to_bbf_authid_user_ext(db_datawriter, DB_DATAWRITER, dbname, NULL, NULL, true, false, false); /* * For master, tempdb and msdb databases, the guest user will be @@ -255,6 +279,12 @@ add_fixed_user_roles_to_bbf_authid_user_ext(const char *dbname) add_to_bbf_authid_user_ext(guest, "guest", dbname, "guest", NULL, false, true, false); else add_to_bbf_authid_user_ext(guest, "guest", dbname, "guest", NULL, false, false, false); + + pfree((char *) dbo); + pfree((char *) db_owner); + pfree((char *) db_accessadmin); + pfree((char *) db_securityadmin); + pfree((char *) guest); } /* @@ -267,11 +297,12 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) List *stmt_list; ListCell *elem; Node *stmt; - int expected_stmts = 10; + int expected_stmts = 12; int i = 0; const char *dbo; const char *db_owner; const char *db_accessadmin; + const char *db_securityadmin; const char *schema; const char *guest_schema; const char *db_datareader; @@ -280,6 +311,7 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) dbo = get_dbo_role_name(dbname); db_owner = get_db_owner_name(dbname); db_accessadmin = get_db_accessadmin_role_name(dbname); + db_securityadmin = get_db_securityadmin_role_name(dbname); schema = get_dbo_schema_name(dbname); guest_schema = get_guest_schema_name(dbname); db_datareader = get_db_datareader_name(dbname); @@ -294,8 +326,11 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) { char *user_name = (char *) lfirst(elem); - if (strcmp(user_name, db_owner) != 0 && strcmp(user_name, dbo) != 0 && - strcmp(user_name, db_accessadmin) != 0 && strcmp(user_name, db_datareader) != 0 && + if (strcmp(user_name, db_owner) != 0 && + strcmp(user_name, dbo) != 0 && + strcmp(user_name, db_accessadmin) != 0 && + strcmp(user_name, db_securityadmin) != 0 && + strcmp(user_name, db_datareader) != 0 && strcmp(user_name, db_datawriter) != 0) { appendStringInfo(&query, "DROP OWNED BY dummy CASCADE; "); @@ -303,12 +338,16 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) expected_stmts += 2; } } - appendStringInfo(&query, "DROP OWNED BY dummy, dummy, dummy CASCADE; "); + appendStringInfo(&query, "DROP OWNED BY dummy, dummy, dummy, dummy CASCADE; "); - /* Then drop db_accessadmin, db_owner and dbo in that order */ + /* + * Then drop db_datareader, db_datawriter, db_securityadmin, db_accessadmin, + * db_owner and dbo in that order + */ appendStringInfo(&query, "DROP ROLE dummy; "); appendStringInfo(&query, "DROP ROLE dummy; "); - + appendStringInfo(&query, "REVOKE CREATE ON DATABASE dummy FROM dummy; "); + appendStringInfo(&query, "DROP ROLE dummy; "); appendStringInfo(&query, "REVOKE CREATE ON DATABASE dummy FROM dummy; "); appendStringInfo(&query, "DROP ROLE dummy; "); appendStringInfo(&query, "REVOKE CREATE, CONNECT, TEMPORARY ON DATABASE dummy FROM dummy; "); @@ -333,8 +372,11 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) { char *user_name = (char *) lfirst(elem); - if (strcmp(user_name, db_owner) != 0 && strcmp(user_name, dbo) != 0 && - strcmp(user_name, db_accessadmin) != 0 && strcmp(user_name, db_datareader) != 0 && + if (strcmp(user_name, db_owner) != 0 && + strcmp(user_name, dbo) != 0 && + strcmp(user_name, db_accessadmin) != 0 && + strcmp(user_name, db_securityadmin) != 0 && + strcmp(user_name, db_datareader) != 0 && strcmp(user_name, db_datawriter) != 0) { stmt = parsetree_nth_stmt(stmt_list, i++); @@ -346,13 +388,18 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) } stmt = parsetree_nth_stmt(stmt_list, i++); - update_DropOwnedStmt(stmt, list_make3(pstrdup(db_accessadmin), pstrdup(db_owner), pstrdup(dbo))); + update_DropOwnedStmt(stmt, list_make4(pstrdup(db_securityadmin), pstrdup(db_accessadmin), pstrdup(db_owner), pstrdup(dbo))); stmt = parsetree_nth_stmt(stmt_list, i++); update_DropRoleStmt(stmt, db_datareader); stmt = parsetree_nth_stmt(stmt_list, i++); update_DropRoleStmt(stmt, db_datawriter); + stmt = parsetree_nth_stmt(stmt_list, i++); + update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_securityadmin, NULL); + stmt = parsetree_nth_stmt(stmt_list, i++); + update_DropRoleStmt(stmt, db_securityadmin); + stmt = parsetree_nth_stmt(stmt_list, i++); update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_accessadmin, NULL); stmt = parsetree_nth_stmt(stmt_list, i++); @@ -366,6 +413,13 @@ gen_dropdb_subcmds(const char *dbname, List *db_users) stmt = parsetree_nth_stmt(stmt_list, i++); update_DropRoleStmt(stmt, dbo); + pfree((char *) dbo); + pfree((char *) db_owner); + pfree((char *) db_accessadmin); + pfree((char *) db_securityadmin); + pfree((char *) schema); + pfree((char *) guest_schema); + return stmt_list; } @@ -1417,12 +1471,14 @@ create_db_roles_in_database(const char *dbname, List *parsetree_list) int i = 0; char *db_owner; char *db_accessadmin; + char *db_securityadmin; char *db_datareader; char *db_datawriter; int16 dbid = get_db_id(dbname); db_owner = get_db_owner_name(dbname); db_accessadmin = get_db_accessadmin_role_name(dbname); + db_securityadmin = get_db_securityadmin_role_name(dbname); db_datareader = get_db_datareader_name(dbname); db_datawriter = get_db_datawriter_name(dbname); @@ -1430,6 +1486,7 @@ create_db_roles_in_database(const char *dbname, List *parsetree_list) rolname_same_as_db_rolname(db_accessadmin); rolname_same_as_db_rolname(db_datareader); rolname_same_as_db_rolname(db_datawriter); + rolname_same_as_db_rolname(db_securityadmin); stmt = parsetree_nth_stmt(parsetree_list, i++); update_CreateRoleStmt(stmt, db_datareader, db_owner, NULL); @@ -1443,6 +1500,12 @@ create_db_roles_in_database(const char *dbname, List *parsetree_list) stmt = parsetree_nth_stmt(parsetree_list, i++); update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_accessadmin, NULL); + stmt = parsetree_nth_stmt(parsetree_list, i++); + update_CreateRoleStmt(stmt, db_securityadmin, db_owner, NULL); + + stmt = parsetree_nth_stmt(parsetree_list, i++); + update_GrantStmt(stmt, get_database_name(MyDatabaseId), NULL, db_securityadmin, NULL); + GetUserIdAndSecContext(&save_userid, &save_sec_context); PG_TRY(); @@ -1451,8 +1514,9 @@ create_db_roles_in_database(const char *dbname, List *parsetree_list) SetConfigOption("createrole_self_grant", "inherit", PGC_USERSET, PGC_S_OVERRIDE); add_to_bbf_authid_user_ext(db_accessadmin, DB_ACCESSADMIN, dbname, NULL, NULL, true, true, false); - add_to_bbf_authid_user_ext(db_datareader, DB_DATAREADER, dbname, NULL, NULL, true, true, false); - add_to_bbf_authid_user_ext(db_datawriter, DB_DATAWRITER, dbname, NULL, NULL, true, true, false); + add_to_bbf_authid_user_ext(db_securityadmin, DB_SECURITYADMIN, dbname, NULL, NULL, true, false, false); + add_to_bbf_authid_user_ext(db_datareader, DB_DATAREADER, dbname, NULL, NULL, true, false, false); + add_to_bbf_authid_user_ext(db_datawriter, DB_DATAWRITER, dbname, NULL, NULL, true, false, false); foreach(parsetree_item, parsetree_list) { @@ -1492,6 +1556,7 @@ create_db_roles_in_database(const char *dbname, List *parsetree_list) SetUserIdAndSecContext(save_userid, save_sec_context); pfree(db_owner); pfree(db_accessadmin); + pfree(db_securityadmin); pfree(db_datareader); pfree(db_datawriter); } @@ -1540,6 +1605,9 @@ create_db_roles_during_upgrade(PG_FUNCTION_ARGS) appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); appendStringInfo(&query, "GRANT CREATE ON DATABASE dummy TO dummy; "); + appendStringInfo(&query, "CREATE ROLE dummy ROLE dummy; "); + appendStringInfo(&query, "GRANT CREATE ON DATABASE dummy TO dummy; "); + parsetree_list = raw_parser(query.data, RAW_PARSE_DEFAULT); sysdatabase_rel = table_open(sysdatabases_oid, RowExclusiveLock); diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index d6c40856e5f..5dc8949d0f8 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -34,6 +34,7 @@ #include "common/logging.h" #include "executor/execExpr.h" #include "funcapi.h" +#include "libpq/libpq.h" #include "miscadmin.h" #include "nodes/makefuncs.h" #include "nodes/nodeFuncs.h" @@ -176,6 +177,7 @@ static bool pltsql_bbfCustomProcessUtility(ParseState *pstate, ParamListInfo params, QueryCompletion *qc); extern void pltsql_bbfSelectIntoUtility(ParseState *pstate, PlannedStmt *pstmt, const char *queryString, QueryEnvironment *queryEnv, ParamListInfo params, QueryCompletion *qc, ObjectAddress *address); +static void handle_grantstmt_for_dbsecadmin(ObjectType objType, Oid objId, Oid ownerId, AclMode privileges, Oid *grantorId, AclMode *grantOptions); /***************************************** * Executor Hooks @@ -283,6 +285,7 @@ static pltsql_strpos_non_determinstic_hook_type prev_pltsql_strpos_non_determins static pltsql_replace_non_determinstic_hook_type prev_pltsql_replace_non_determinstic_hook = NULL; static pltsql_is_partitioned_table_reloptions_allowed_hook_type prev_pltsql_is_partitioned_table_reloptions_allowed_hook = NULL; static ExecFuncProc_AclCheck_hook_type prev_ExecFuncProc_AclCheck_hook = NULL; +static bbf_execute_grantstmt_as_dbsecadmin_hook_type prev_bbf_execute_grantstmt_as_dbsecadmin_hook = NULL; /***************************************** * Install / Uninstall @@ -495,6 +498,9 @@ InstallExtendedHooks(void) prev_ExecFuncProc_AclCheck_hook = ExecFuncProc_AclCheck_hook; ExecFuncProc_AclCheck_hook = pltsql_ExecFuncProc_AclCheck; + + prev_bbf_execute_grantstmt_as_dbsecadmin_hook = bbf_execute_grantstmt_as_dbsecadmin_hook; + bbf_execute_grantstmt_as_dbsecadmin_hook = handle_grantstmt_for_dbsecadmin; pltsql_get_object_identity_event_trigger_hook = pltsql_get_object_identity_event_trigger; } @@ -565,6 +571,7 @@ UninstallExtendedHooks(void) pltsql_replace_non_determinstic_hook = prev_pltsql_replace_non_determinstic_hook; pltsql_is_partitioned_table_reloptions_allowed_hook = prev_pltsql_is_partitioned_table_reloptions_allowed_hook; ExecFuncProc_AclCheck_hook = prev_ExecFuncProc_AclCheck_hook; + bbf_execute_grantstmt_as_dbsecadmin_hook = prev_bbf_execute_grantstmt_as_dbsecadmin_hook; bbf_InitializeParallelDSM_hook = NULL; bbf_ParallelWorkerMain_hook = NULL; @@ -5626,3 +5633,89 @@ pltsql_get_object_identity_event_trigger(ObjectAddress* address) } return identity; } + +/* + * Allows execution of GRANT/REVOKE statement if current_user is member of db_securityadmin + * given that GRANT/REVOKE is being executed on current database's object. It is being + * ensured that schema of given object(in GRANT/REVOKE statement) belongs to current database. + */ +static void +handle_grantstmt_for_dbsecadmin(ObjectType objType, Oid objId, Oid ownerId, + AclMode privileges, Oid *grantorId, AclMode *grantOptions) +{ + ObjectAddress address; + Oid classid = InvalidOid; + Oid schema_oid = InvalidOid; + + /* + * Return if any of following condition is true + * 1. Not a TDS client + * 2. Not a TSQL dialect + * 3. Grantor is same as owner OR Grantor already has all the required privileges. + * This means already the best grantor has been selected using select_best_grantor(). + */ + if (!MyProcPort->is_tds_conn || + sql_dialect != SQL_DIALECT_TSQL || + *grantorId == ownerId || + *grantOptions == ACL_GRANT_OPTION_FOR(privileges)) + return; + + switch(objType) + { + case OBJECT_TABLE: + case OBJECT_COLUMN: + case OBJECT_VIEW: + classid = RelationRelationId; + break; + case OBJECT_FUNCTION: + case OBJECT_PROCEDURE: + classid = ProcedureRelationId; + break; + case OBJECT_SCHEMA: + classid = NamespaceRelationId; + break; + default: + break; + } + + if (!OidIsValid(classid)) + return; + + if (classid == NamespaceRelationId) + { + schema_oid = objId; + } + else + { + ObjectAddressSet(address, classid, objId); + schema_oid = get_object_namespace(&address); + } + + if (OidIsValid(schema_oid)) + { + /* + * Don't allow if object's schema is not from current database OR + * it is a shared schema. + */ + if (!is_schema_from_db(schema_oid, get_cur_db_id())) + { + return; + } + else + { + /* + * Check if current user is member of db_securityadmin role. + * If so, then grant/revoke the requested privileges by overriding + * grantId with ownerId. + */ + if (is_member_of_role(GetUserId(), + get_db_securityadmin_oid(get_current_pltsql_db_name(), false))) + { + *grantorId = ownerId; + *grantOptions = ACL_GRANT_OPTION_FOR(privileges); + return; + } + } + } + return; +} diff --git a/contrib/babelfishpg_tsql/src/multidb.c b/contrib/babelfishpg_tsql/src/multidb.c index b2e230c20c4..de313c67c07 100644 --- a/contrib/babelfishpg_tsql/src/multidb.c +++ b/contrib/babelfishpg_tsql/src/multidb.c @@ -1494,10 +1494,35 @@ get_db_accessadmin_oid(const char *dbname, bool missing_ok) char *db_accessadmin_name = get_db_accessadmin_role_name(dbname); Oid db_accessadmin_oid = get_role_oid(db_accessadmin_name, missing_ok); pfree(db_accessadmin_name); - + return db_accessadmin_oid; } +char * +get_db_securityadmin_role_name(const char *dbname) +{ + char *name = palloc0(MAX_BBF_NAMEDATALEND); + + if (get_migration_mode() == SINGLE_DB && strcmp(dbname, "master") != 0 + && strcmp(dbname, "tempdb") != 0 && strcmp(dbname, "msdb") != 0) + snprintf(name, MAX_BBF_NAMEDATALEND, "%s", DB_SECURITYADMIN); + else + snprintf(name, MAX_BBF_NAMEDATALEND, "%s_%s", dbname, DB_SECURITYADMIN); + + truncate_identifier(name, strlen(name), false); + return name; +} + +Oid +get_db_securityadmin_oid(const char *dbname, bool missing_ok) +{ + char *db_securityadmin_name = get_db_securityadmin_role_name(dbname); + Oid db_securityadmin_oid = get_role_oid(db_securityadmin_name, missing_ok); + pfree(db_securityadmin_name); + + return db_securityadmin_oid; +} + char * get_guest_schema_name(const char *dbname) { diff --git a/contrib/babelfishpg_tsql/src/multidb.h b/contrib/babelfishpg_tsql/src/multidb.h index f42f51e9fc6..8058d8ed4ec 100644 --- a/contrib/babelfishpg_tsql/src/multidb.h +++ b/contrib/babelfishpg_tsql/src/multidb.h @@ -25,6 +25,8 @@ extern char *get_dbo_role_name(const char *dbname); extern char *get_dbo_role_name_by_mode(const char *dbname, MigrationMode mode); extern char *get_db_owner_name(const char *dbname); extern char *get_db_owner_name_by_mode(const char *dbname, MigrationMode mode); +extern char *get_db_securityadmin_role_name(const char *dbname); +extern Oid get_db_securityadmin_oid(const char *dbname, bool missing_ok); extern Oid get_db_owner_oid(const char *dbname, bool missing_ok); extern char *get_db_accessadmin_role_name(const char *dbname); extern Oid get_db_accessadmin_oid(const char *dbname, bool missing_ok); diff --git a/contrib/babelfishpg_tsql/src/pl_exec-2.c b/contrib/babelfishpg_tsql/src/pl_exec-2.c index cbc28057e98..f8c36728dfe 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec-2.c +++ b/contrib/babelfishpg_tsql/src/pl_exec-2.c @@ -3795,9 +3795,14 @@ exec_stmt_grantschema(PLtsql_execstate *estate, PLtsql_stmt_grantschema *stmt) /* * If the login is not the db owner or the login is not the member of - * sysadmin or login is not the schema owner, then it doesn't have the permission to GRANT/REVOKE. + * sysadmin or login is not the schema owner, + * or current_user is not member of db_securityadmin fixed role + * then it doesn't have the permission to GRANT/REVOKE. */ - if (!is_member_of_role(GetSessionUserId(), get_sysadmin_oid()) && !login_is_db_owner && !object_ownercheck(NamespaceRelationId, schemaOid, GetUserId())) + if (!is_member_of_role(GetSessionUserId(), get_sysadmin_oid()) && + !login_is_db_owner && + !object_ownercheck(NamespaceRelationId, schemaOid, GetUserId()) && + !has_privs_of_role(GetUserId(), get_db_securityadmin_oid(dbname, false))) ereport(ERROR, (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), errmsg("Cannot find the schema \"%s\", because it does not exist or you do not have permission.", stmt->schema_name))); diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index 3077708658a..8dd32cb080e 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -3005,11 +3005,13 @@ bbf_ProcessUtility(PlannedStmt *pstmt, char *current_db_name = get_cur_db_name(); if (has_privs_of_role(GetUserId(), get_db_owner_oid(current_db_name, false)) || - (isuser && has_privs_of_role(GetUserId(), get_db_accessadmin_oid(current_db_name, false)))) + (isuser && has_privs_of_role(GetUserId(), get_db_accessadmin_oid(current_db_name, false))) || + (isrole && has_privs_of_role(GetUserId(), get_db_securityadmin_oid(current_db_name, false)))) { /* * members of db_owner can create roles and users * members of db_accessadmin can only create users + * members of db_securityadmin can only create db roles */ } else @@ -3306,13 +3308,13 @@ bbf_ProcessUtility(PlannedStmt *pstmt, char *db_name = get_cur_db_name(); bool is_member_of_db_owner = false; bool is_member_of_db_accessadmin = false; + bool is_member_of_db_securityadmin = false; int save_sec_context; Oid save_userid; Oid db_owner = get_db_owner_oid(db_name, false); Oid db_accessadmin = get_db_accessadmin_oid(db_name, false); + Oid db_securityadmin = get_db_securityadmin_oid(db_name, false); Oid user_oid = get_role_oid(stmt->role->rolename, false); - - /* db principal being altered should be a user or role in the current active logical database */ if ((isuser && get_db_principal_kind(user_oid, db_name) != BBF_USER) || (isrole && get_db_principal_kind(user_oid, db_name) != BBF_ROLE)) ereport(ERROR, @@ -3324,6 +3326,9 @@ bbf_ProcessUtility(PlannedStmt *pstmt, if (!is_member_of_db_owner && isuser) is_member_of_db_accessadmin = has_privs_of_role(GetUserId(), db_accessadmin); + if (!is_member_of_db_owner && isrole) + is_member_of_db_securityadmin = has_privs_of_role(GetUserId(), db_securityadmin); + /* * Check if the current user has privileges. */ @@ -3351,11 +3356,13 @@ bbf_ProcessUtility(PlannedStmt *pstmt, else if (strcmp(defel->defname, "rename") == 0) { if (is_member_of_db_owner || (isuser && is_member_of_db_accessadmin && - !has_privs_of_role(user_oid, db_owner))) + !has_privs_of_role(user_oid, db_owner)) || + (isrole && is_member_of_db_securityadmin && !has_privs_of_role(user_oid, db_owner))) { /* * members of db_owner can rename any role or user * members of db_accessadmin can rename users who are not members of db_owner + * member of db_securityadmin can rename users who are not members of db_owner */ } else @@ -3469,6 +3476,7 @@ bbf_ProcessUtility(PlannedStmt *pstmt, { Oid db_owner = get_db_owner_oid(db_name, false); Oid db_accessadmin = get_db_accessadmin_oid(db_name, false); + Oid db_securityadmin = get_db_securityadmin_oid(db_name, false); foreach(item, stmt->roles) { @@ -3498,11 +3506,13 @@ bbf_ProcessUtility(PlannedStmt *pstmt, (errcode(ERRCODE_CHECK_VIOLATION), errmsg("Cannot drop the %s '%s'.", db_principal_type, rolspec->rolename))); - if (has_privs_of_role(GetUserId(), db_owner) || (drop_user && has_privs_of_role(GetUserId(), db_accessadmin))) + if (has_privs_of_role(GetUserId(), db_owner) || (drop_user && has_privs_of_role(GetUserId(), db_accessadmin)) || + (drop_role && has_privs_of_role(GetUserId(), db_securityadmin))) { /* * db_owner can drop any user or role in database * db_accessadmin can drop users in a database + * db_securityadmin can drop roles in a database */ } else @@ -3717,6 +3727,7 @@ bbf_ProcessUtility(PlannedStmt *pstmt, { const char *db_name = get_current_pltsql_db_name(); Oid db_accessadmin = get_db_accessadmin_oid(db_name, false); + Oid db_securityadmin = get_db_securityadmin_oid(db_name, false); owner_oid = get_rolespec_oid(rolspec, true); /* @@ -3725,8 +3736,9 @@ bbf_ProcessUtility(PlannedStmt *pstmt, * to current user and later alter schema owner using bbf_role_admin */ if (!member_can_set_role(GetUserId(), owner_oid) && - has_privs_of_role(GetUserId(), db_accessadmin) && - (get_db_principal_kind(owner_oid, db_name))) + (has_privs_of_role(GetUserId(), db_accessadmin) || + has_privs_of_role(GetUserId(), db_securityadmin)) && + get_db_principal_kind(owner_oid, db_name)) { create_schema->authrole = NULL; alter_owner = true; @@ -4211,6 +4223,12 @@ bbf_ProcessUtility(PlannedStmt *pstmt, char *db_datawriter = get_db_datawriter_name(dbname); char *db_accessadmin = get_db_accessadmin_role_name(dbname); + /* + * NOTE: GRANT/REVOKE on OBJECT(schema-contained)/SCHEMA are allowed + * if current_user is member of db_securityadmin via engine hooks. + * Please refer handle_grantstmt_for_dbsecadmin() function for more details. + */ + /* Ignore when GRANT statement has no specific named object. */ if (sql_dialect != SQL_DIALECT_TSQL || grant->targtype != ACL_TARGET_OBJECT) break; diff --git a/contrib/babelfishpg_tsql/src/pltsql.h b/contrib/babelfishpg_tsql/src/pltsql.h index 528fd894cae..6388386a84e 100644 --- a/contrib/babelfishpg_tsql/src/pltsql.h +++ b/contrib/babelfishpg_tsql/src/pltsql.h @@ -1993,20 +1993,22 @@ extern bool insert_bulk_check_constraints; #define DBO "dbo" #define DB_OWNER "db_owner" #define DB_ACCESSADMIN "db_accessadmin" +#define DB_SECURITYADMIN "db_securityadmin" #define DB_DATAREADER "db_datareader" #define DB_DATAWRITER "db_datawriter" #define IS_BBF_BUILT_IN_DB(dbname) \ - (strncmp(dbname, "master", 6) == 0 || \ - strncmp(dbname, "tempdb", 6) == 0 || \ - strncmp(dbname, "msdb", 4) == 0) + (strcmp(dbname, "master") == 0 || \ + strcmp(dbname, "tempdb") == 0 || \ + strcmp(dbname, "msdb") == 0) #define IS_FIXED_DB_PRINCIPAL(rolname) \ - (strncmp(rolname, DBO, 3) == 0 || \ - strncmp(rolname, DB_OWNER, 8) == 0 || \ - strncmp(rolname, DB_ACCESSADMIN, 14) == 0 || \ - strncmp(rolname, DB_DATAREADER, 13) == 0 || \ - strncmp(rolname, DB_DATAWRITER, 13) == 0) + (strcmp(rolname, DBO) == 0 || \ + strcmp(rolname, DB_OWNER) == 0 || \ + strcmp(rolname, DB_ACCESSADMIN) == 0 || \ + strcmp(rolname, DB_SECURITYADMIN) == 0 || \ + strcmp(rolname, DB_DATAREADER) == 0 || \ + strcmp(rolname, DB_DATAWRITER) == 0) /********************************************************************** * Function declarations diff --git a/contrib/babelfishpg_tsql/src/rolecmds.c b/contrib/babelfishpg_tsql/src/rolecmds.c index 5253171557f..e7330fb04ce 100644 --- a/contrib/babelfishpg_tsql/src/rolecmds.c +++ b/contrib/babelfishpg_tsql/src/rolecmds.c @@ -1846,11 +1846,16 @@ check_alter_role_stmt(GrantRoleStmt *stmt) errmsg("Cannot alter the role '%s', because it does not exist or you do not have permission.", original_user_name))); /* - * Disallow ALTER ROLE if 1. Current login doesn't have permission on the - * granted role, or 2. The current user is trying to add/drop itself from - * the granted role + * Disallow ALTER ROLE if + * 1. Current login doesn't have permission on the granted role + * OR + * 2. Granted role is not a fixed db role or current user is a member of db_securityadmin + * OR + * 3. The current user is trying to add/drop itself from the granted role */ - if (!has_privs_of_role(GetSessionUserId(), granted) || + if ((!has_privs_of_role(GetSessionUserId(), granted) && + !(get_db_principal_kind(granted, db_name) == BBF_ROLE && + has_privs_of_role(GetUserId(), get_db_securityadmin_oid(get_current_pltsql_db_name(), false)))) || grantee == GetUserId()) ereport(ERROR, (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), diff --git a/test/JDBC/expected/BABEL-2403.out b/test/JDBC/expected/BABEL-2403.out index 20cd61fe4f1..6ee9a44d8bb 100644 --- a/test/JDBC/expected/BABEL-2403.out +++ b/test/JDBC/expected/BABEL-2403.out @@ -121,6 +121,12 @@ name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext m text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} name#!#pg_catalog#!#proname#!#{"Rule": " in babelfish_function_ext must also exist in pg_proc"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} @@ -232,6 +238,12 @@ name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext m text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} name#!#pg_catalog#!#proname#!#{"Rule": " in babelfish_function_ext must also exist in pg_proc"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} diff --git a/test/JDBC/expected/BABEL-5119-vu-verify.out b/test/JDBC/expected/BABEL-5119-vu-verify.out index fbccec69708..6b16ff446d0 100644 --- a/test/JDBC/expected/BABEL-5119-vu-verify.out +++ b/test/JDBC/expected/BABEL-5119-vu-verify.out @@ -743,23 +743,3 @@ GO ~~ROW COUNT: 1~~ -- terminate-tsql-conn user=login_babel5119_2 password=12345678 - --- tsql database=BABEL5119_db -CREATE SCHEMA BABEL5119_schema; -GO - -SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) - FROM ( - SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() - ) AS a - JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) - WHERE u.database_name = 'BABEL5119_db' - ORDER BY u.orig_username; -GO -~~START~~ -nvarchar#!#varchar -db_accessadmin#!#=C -dbo#!#=CTc -~~END~~ - --- terminate-tsql-conn database=BABEL5119_db diff --git a/test/JDBC/expected/BABEL-5119_before_16_5-vu-verify.out b/test/JDBC/expected/BABEL-5119_before_16_5-vu-verify.out index 765d01674cb..08176d1a088 100644 --- a/test/JDBC/expected/BABEL-5119_before_16_5-vu-verify.out +++ b/test/JDBC/expected/BABEL-5119_before_16_5-vu-verify.out @@ -743,22 +743,3 @@ GO ~~ROW COUNT: 1~~ -- terminate-tsql-conn user=login_babel5119_2 password=12345678 - --- tsql database=BABEL5119_db -CREATE SCHEMA BABEL5119_schema; -GO - -SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) - FROM ( - SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() - ) AS a - JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) - WHERE u.database_name = 'BABEL5119_db' - ORDER BY u.orig_username; -GO -~~START~~ -nvarchar#!#varchar -dbo#!#=CTc -~~END~~ - --- terminate-tsql-conn database=BABEL5119_db diff --git a/test/JDBC/expected/BABEL-LOGIN-USER-EXT.out b/test/JDBC/expected/BABEL-LOGIN-USER-EXT.out index 999d304c1bc..52de3e860b3 100644 --- a/test/JDBC/expected/BABEL-LOGIN-USER-EXT.out +++ b/test/JDBC/expected/BABEL-LOGIN-USER-EXT.out @@ -698,24 +698,28 @@ db1_db_accessadmin#!#db_accessadmin#!##!#db1#!# db1_db_datareader#!#db_datareader#!##!#db1#!# db1_db_datawriter#!#db_datawriter#!##!#db1#!# db1_db_owner#!#db_owner#!##!#db1#!# +db1_db_securityadmin#!#db_securityadmin#!##!#db1#!# db1_dbo#!#dbo#!##!#db1#!#dbo db1_guest#!#guest#!##!#db1#!#guest master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -883,18 +887,21 @@ master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -943,30 +950,35 @@ db1_db_accessadmin#!##!#db_accessadmin#!#db1#!# db1_db_datareader#!##!#db_datareader#!#db1#!# db1_db_datawriter#!##!#db_datawriter#!#db1#!# db1_db_owner#!##!#db_owner#!#db1#!# +db1_db_securityadmin#!##!#db_securityadmin#!#db1#!# db1_dbo#!##!#dbo#!#db1#!#dbo db1_guest#!##!#guest#!#db1#!#guest db2_db_accessadmin#!##!#db_accessadmin#!#db2#!# db2_db_datareader#!##!#db_datareader#!#db2#!# db2_db_datawriter#!##!#db_datawriter#!#db2#!# db2_db_owner#!##!#db_owner#!#db2#!# +db2_db_securityadmin#!##!#db_securityadmin#!#db2#!# db2_dbo#!##!#dbo#!#db2#!#dbo db2_guest#!##!#guest#!#db2#!#guest master_db_accessadmin#!##!#db_accessadmin#!#master#!# master_db_datareader#!##!#db_datareader#!#master#!# master_db_datawriter#!##!#db_datawriter#!#master#!# master_db_owner#!##!#db_owner#!#master#!# +master_db_securityadmin#!##!#db_securityadmin#!#master#!# master_dbo#!##!#dbo#!#master#!#dbo master_guest#!##!#guest#!#master#!#guest msdb_db_accessadmin#!##!#db_accessadmin#!#msdb#!# msdb_db_datareader#!##!#db_datareader#!#msdb#!# msdb_db_datawriter#!##!#db_datawriter#!#msdb#!# msdb_db_owner#!##!#db_owner#!#msdb#!# +msdb_db_securityadmin#!##!#db_securityadmin#!#msdb#!# msdb_dbo#!##!#dbo#!#msdb#!#dbo msdb_guest#!##!#guest#!#msdb#!#guest tempdb_db_accessadmin#!##!#db_accessadmin#!#tempdb#!# tempdb_db_datareader#!##!#db_datareader#!#tempdb#!# tempdb_db_datawriter#!##!#db_datawriter#!#tempdb#!# tempdb_db_owner#!##!#db_owner#!#tempdb#!# +tempdb_db_securityadmin#!##!#db_securityadmin#!#tempdb#!# tempdb_dbo#!##!#dbo#!#tempdb#!#dbo tempdb_guest#!##!#guest#!#tempdb#!#guest ~~END~~ @@ -984,6 +996,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# @@ -1019,6 +1032,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# @@ -1156,24 +1170,28 @@ db2_db_accessadmin#!#db_accessadmin#!##!#db2#!# db2_db_datareader#!#db_datareader#!##!#db2#!# db2_db_datawriter#!#db_datawriter#!##!#db2#!# db2_db_owner#!#db_owner#!##!#db2#!# +db2_db_securityadmin#!#db_securityadmin#!##!#db2#!# db2_dbo#!#dbo#!##!#db2#!#dbo db2_guest#!#guest#!##!#db2#!#guest master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -1192,18 +1210,21 @@ master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -1479,6 +1500,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1499,6 +1521,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1518,6 +1541,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1536,6 +1560,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA diff --git a/test/JDBC/expected/BABEL-USER.out b/test/JDBC/expected/BABEL-USER.out index ba9aa1de6e9..086c67743cc 100644 --- a/test/JDBC/expected/BABEL-USER.out +++ b/test/JDBC/expected/BABEL-USER.out @@ -53,24 +53,28 @@ db1_db_accessadmin#!##!#db_accessadmin#!#db1#!# db1_db_datareader#!##!#db_datareader#!#db1#!# db1_db_datawriter#!##!#db_datawriter#!#db1#!# db1_db_owner#!##!#db_owner#!#db1#!# +db1_db_securityadmin#!##!#db_securityadmin#!#db1#!# db1_dbo#!##!#dbo#!#db1#!#dbo db1_guest#!##!#guest#!#db1#!#guest master_db_accessadmin#!##!#db_accessadmin#!#master#!# master_db_datareader#!##!#db_datareader#!#master#!# master_db_datawriter#!##!#db_datawriter#!#master#!# master_db_owner#!##!#db_owner#!#master#!# +master_db_securityadmin#!##!#db_securityadmin#!#master#!# master_dbo#!##!#dbo#!#master#!#dbo master_guest#!##!#guest#!#master#!#guest msdb_db_accessadmin#!##!#db_accessadmin#!#msdb#!# msdb_db_datareader#!##!#db_datareader#!#msdb#!# msdb_db_datawriter#!##!#db_datawriter#!#msdb#!# msdb_db_owner#!##!#db_owner#!#msdb#!# +msdb_db_securityadmin#!##!#db_securityadmin#!#msdb#!# msdb_dbo#!##!#dbo#!#msdb#!#dbo msdb_guest#!##!#guest#!#msdb#!#guest tempdb_db_accessadmin#!##!#db_accessadmin#!#tempdb#!# tempdb_db_datareader#!##!#db_datareader#!#tempdb#!# tempdb_db_datawriter#!##!#db_datawriter#!#tempdb#!# tempdb_db_owner#!##!#db_owner#!#tempdb#!# +tempdb_db_securityadmin#!##!#db_securityadmin#!#tempdb#!# tempdb_dbo#!##!#dbo#!#tempdb#!#dbo tempdb_guest#!##!#guest#!#tempdb#!#guest ~~END~~ @@ -88,6 +92,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# diff --git a/test/JDBC/expected/Test-sp_helpdbfixedrole-dep-vu-verify.out b/test/JDBC/expected/Test-sp_helpdbfixedrole-dep-vu-verify.out index 3079345d3fe..8a423a1ceac 100644 --- a/test/JDBC/expected/Test-sp_helpdbfixedrole-dep-vu-verify.out +++ b/test/JDBC/expected/Test-sp_helpdbfixedrole-dep-vu-verify.out @@ -4,6 +4,7 @@ GO varchar#!#nvarchar db_owner#!#DB Owners db_accessadmin#!#DB Access Administrators +db_securityadmin#!#DB Security Administrators db_datareader#!#DB Data Reader db_datawriter#!#DB Data Writer ~~END~~ @@ -21,7 +22,7 @@ SELECT dbo.test_sp_helpdbfixedrole_func() GO ~~START~~ int -4 +5 ~~END~~ @@ -29,7 +30,7 @@ SELECT * FROM test_sp_helpdbfixedrole_view GO ~~START~~ int -4 +5 ~~END~~ @@ -37,6 +38,7 @@ EXEC test_sp_helpdbfixedrole_proc 'DB_securityadmin' GO ~~START~~ varchar#!#nvarchar +db_securityadmin#!#DB Security Administrators ~~END~~ diff --git a/test/JDBC/expected/Test-sp_helpdbfixedrole-vu-verify.out b/test/JDBC/expected/Test-sp_helpdbfixedrole-vu-verify.out index 5eee87026f8..24ff4bb1c38 100644 --- a/test/JDBC/expected/Test-sp_helpdbfixedrole-vu-verify.out +++ b/test/JDBC/expected/Test-sp_helpdbfixedrole-vu-verify.out @@ -1,6 +1,6 @@ INSERT INTO test_sp_helpdbfixedrole_tbl (DbFixedRole, Description) EXEC sp_helpdbfixedrole GO -~~ROW COUNT: 4~~ +~~ROW COUNT: 5~~ SELECT DbFixedRole, Description FROM test_sp_helpdbfixedrole_tbl @@ -9,6 +9,7 @@ GO varchar#!#nvarchar db_owner#!#DB Owners db_accessadmin#!#DB Access Administrators +db_securityadmin#!#DB Security Administrators db_datareader#!#DB Data Reader db_datawriter#!#DB Data Writer ~~END~~ @@ -55,6 +56,8 @@ GO INSERT INTO test_sp_helpdbfixedrole_tbl (DbFixedRole, Description) EXEC sp_helpdbfixedrole 'DB_securityadmin' GO +~~ROW COUNT: 1~~ + INSERT INTO test_sp_helpdbfixedrole_tbl (DbFixedRole, Description) EXEC sp_helpdbfixedrole 'db_ddladmin ' GO INSERT INTO test_sp_helpdbfixedrole_tbl (DbFixedRole, Description) EXEC sp_helpdbfixedrole 'DB_backupoperator ' @@ -77,6 +80,7 @@ GO ~~START~~ varchar#!#nvarchar db_accessadmin#!#DB Access Administrators +db_securityadmin#!#DB Security Administrators db_datareader#!#DB Data Reader db_datawriter#!#DB Data Writer ~~END~~ diff --git a/test/JDBC/expected/Test_alter_db_rename-vu-verify.out b/test/JDBC/expected/Test_alter_db_rename-vu-verify.out index 687dd6e3cc3..c435e0dcbde 100644 --- a/test/JDBC/expected/Test_alter_db_rename-vu-verify.out +++ b/test/JDBC/expected/Test_alter_db_rename-vu-verify.out @@ -23,6 +23,7 @@ rename_db_database1_db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 rename_db_database1_db_datareader#!##!#db_datareader#!#rename_db_database1 rename_db_database1_db_datawriter#!##!#db_datawriter#!#rename_db_database1 rename_db_database1_db_owner#!##!#db_owner#!#rename_db_database1 +rename_db_database1_db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 rename_db_database1_dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_login2#!#rename_db_login2#!#rename_db_login2#!#rename_db_database1 @@ -87,6 +88,7 @@ rename_db_database2_db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 rename_db_database2_db_datareader#!##!#db_datareader#!#rename_db_database2 rename_db_database2_db_datawriter#!##!#db_datawriter#!#rename_db_database2 rename_db_database2_db_owner#!##!#db_owner#!#rename_db_database2 +rename_db_database2_db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 rename_db_database2_dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_login2#!#rename_db_login2#!#rename_db_login2#!#rename_db_database2 @@ -198,6 +200,7 @@ thisnewdatabasenameiscasesensit4e1f355d810759b9f1a59b04496ed2e1#!##!#guest#!#thi thisnewdatabasenameiscasesensit72e4dcc7ed25f5536033cf547cd7f001#!##!#db_owner#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e thisnewdatabasenameiscasesensit7de06ed1a7bed768d6641b3e7841314c#!##!#db_datareader#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e thisnewdatabasenameiscasesensit944678472843354d6b3a4354630249a8#!##!#db_accessadmin#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e +thisnewdatabasenameiscasesensit9bafb01adb257f37faf768d9b70d81a7#!##!#db_securityadmin#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e thisnewdatabasenameiscasesensitc4313f9adf0e47cfa5aca25228e02f29#!##!#dbo#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e thisnewdatabasenameiscasesensitfa060d610d6e6cd0271b6ce99b258bcc#!##!#db_datawriter#!#thisnewdatabasenameiscasesensit44f3247005ec268e1a10c736599cfb7e ~~END~~ diff --git a/test/JDBC/expected/Test_rename_db_single-db.out b/test/JDBC/expected/Test_rename_db_single-db.out index 541d3593388..b43269cf494 100644 --- a/test/JDBC/expected/Test_rename_db_single-db.out +++ b/test/JDBC/expected/Test_rename_db_single-db.out @@ -36,6 +36,7 @@ rename_db_database1_db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 rename_db_database1_db_datareader#!##!#db_datareader#!#rename_db_database1 rename_db_database1_db_datawriter#!##!#db_datawriter#!#rename_db_database1 rename_db_database1_db_owner#!##!#db_owner#!#rename_db_database1 +rename_db_database1_db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 rename_db_database1_dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -87,6 +88,7 @@ rename_db_database2_db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 rename_db_database2_db_datareader#!##!#db_datareader#!#rename_db_database2 rename_db_database2_db_datawriter#!##!#db_datawriter#!#rename_db_database2 rename_db_database2_db_owner#!##!#db_owner#!#rename_db_database2 +rename_db_database2_db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 rename_db_database2_dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -138,6 +140,7 @@ rename_db_database1_db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 rename_db_database1_db_datareader#!##!#db_datareader#!#rename_db_database1 rename_db_database1_db_datawriter#!##!#db_datawriter#!#rename_db_database1 rename_db_database1_db_owner#!##!#db_owner#!#rename_db_database1 +rename_db_database1_db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 rename_db_database1_dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -189,6 +192,7 @@ rename_db_database2_db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 rename_db_database2_db_datareader#!##!#db_datareader#!#rename_db_database2 rename_db_database2_db_datawriter#!##!#db_datawriter#!#rename_db_database2 rename_db_database2_db_owner#!##!#db_owner#!#rename_db_database2 +rename_db_database2_db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 rename_db_database2_dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -252,6 +256,7 @@ rename_db_database1_db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 rename_db_database1_db_datareader#!##!#db_datareader#!#rename_db_database1 rename_db_database1_db_datawriter#!##!#db_datawriter#!#rename_db_database1 rename_db_database1_db_owner#!##!#db_owner#!#rename_db_database1 +rename_db_database1_db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 rename_db_database1_dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -303,6 +308,7 @@ rename_db_database2_db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 rename_db_database2_db_datareader#!##!#db_datareader#!#rename_db_database2 rename_db_database2_db_datawriter#!##!#db_datawriter#!#rename_db_database2 rename_db_database2_db_owner#!##!#db_owner#!#rename_db_database2 +rename_db_database2_db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 rename_db_database2_dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -354,6 +360,7 @@ rename_db_database1_db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 rename_db_database1_db_datareader#!##!#db_datareader#!#rename_db_database1 rename_db_database1_db_datawriter#!##!#db_datawriter#!#rename_db_database1 rename_db_database1_db_owner#!##!#db_owner#!#rename_db_database1 +rename_db_database1_db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 rename_db_database1_dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -405,6 +412,7 @@ rename_db_database2_db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 rename_db_database2_db_datareader#!##!#db_datareader#!#rename_db_database2 rename_db_database2_db_datawriter#!##!#db_datawriter#!#rename_db_database2 rename_db_database2_db_owner#!##!#db_owner#!#rename_db_database2 +rename_db_database2_db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 rename_db_database2_dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 diff --git a/test/JDBC/expected/Test_sp_rename_database-vu-verify.out b/test/JDBC/expected/Test_sp_rename_database-vu-verify.out index 25ed3c274af..1900036990c 100644 --- a/test/JDBC/expected/Test_sp_rename_database-vu-verify.out +++ b/test/JDBC/expected/Test_sp_rename_database-vu-verify.out @@ -23,6 +23,7 @@ sp_rename_database1_db_accessadmin#!##!#db_accessadmin#!#sp_rename_database1 sp_rename_database1_db_datareader#!##!#db_datareader#!#sp_rename_database1 sp_rename_database1_db_datawriter#!##!#db_datawriter#!#sp_rename_database1 sp_rename_database1_db_owner#!##!#db_owner#!#sp_rename_database1 +sp_rename_database1_db_securityadmin#!##!#db_securityadmin#!#sp_rename_database1 sp_rename_database1_dbo#!##!#dbo#!#sp_rename_database1 sp_rename_database1_guest#!##!#guest#!#sp_rename_database1 sp_rename_database1_sp_rename_login2#!#sp_rename_login2#!#sp_rename_login2#!#sp_rename_database1 @@ -87,6 +88,7 @@ sp_rename_database2_db_accessadmin#!##!#db_accessadmin#!#sp_rename_database2 sp_rename_database2_db_datareader#!##!#db_datareader#!#sp_rename_database2 sp_rename_database2_db_datawriter#!##!#db_datawriter#!#sp_rename_database2 sp_rename_database2_db_owner#!##!#db_owner#!#sp_rename_database2 +sp_rename_database2_db_securityadmin#!##!#db_securityadmin#!#sp_rename_database2 sp_rename_database2_dbo#!##!#dbo#!#sp_rename_database2 sp_rename_database2_guest#!##!#guest#!#sp_rename_database2 sp_rename_database2_sp_rename_login2#!#sp_rename_login2#!#sp_rename_login2#!#sp_rename_database2 @@ -206,6 +208,7 @@ sp_rename_thisnewdatabasenameis21f79a8b66248a73068dca6edd5b0ca3#!##!#guest#!#sp_ sp_rename_thisnewdatabasenameis95c235131f6db63ef16f222aa48d0554#!##!#db_datareader#!#sp_rename_thisnewdatabasenameisb8bd7c94f797959aa629fc2f9e821637 sp_rename_thisnewdatabasenameisa0a5aa90abf2314f4773860fda5e43a2#!##!#db_accessadmin#!#sp_rename_thisnewdatabasenameisb8bd7c94f797959aa629fc2f9e821637 sp_rename_thisnewdatabasenameisc7c7032a834c11dbbbbf4911217c443a#!##!#db_datawriter#!#sp_rename_thisnewdatabasenameisb8bd7c94f797959aa629fc2f9e821637 +sp_rename_thisnewdatabasenameisf37d42f2565acdd17a6e787fa43e9065#!##!#db_securityadmin#!#sp_rename_thisnewdatabasenameisb8bd7c94f797959aa629fc2f9e821637 sp_rename_thisnewdatabasenameisfacf8af797f428fdc401ffddc672894d#!##!#dbo#!#sp_rename_thisnewdatabasenameisb8bd7c94f797959aa629fc2f9e821637 ~~END~~ diff --git a/test/JDBC/expected/Test_sp_renamedb-vu-verify.out b/test/JDBC/expected/Test_sp_renamedb-vu-verify.out index a68d7ab49c5..460a11cb6a6 100644 --- a/test/JDBC/expected/Test_sp_renamedb-vu-verify.out +++ b/test/JDBC/expected/Test_sp_renamedb-vu-verify.out @@ -23,6 +23,7 @@ sp_renamedb_database1_db_accessadmin#!##!#db_accessadmin#!#sp_renamedb_database1 sp_renamedb_database1_db_datareader#!##!#db_datareader#!#sp_renamedb_database1 sp_renamedb_database1_db_datawriter#!##!#db_datawriter#!#sp_renamedb_database1 sp_renamedb_database1_db_owner#!##!#db_owner#!#sp_renamedb_database1 +sp_renamedb_database1_db_securityadmin#!##!#db_securityadmin#!#sp_renamedb_database1 sp_renamedb_database1_dbo#!##!#dbo#!#sp_renamedb_database1 sp_renamedb_database1_guest#!##!#guest#!#sp_renamedb_database1 sp_renamedb_database1_sp_renamedb_login2#!#sp_renamedb_login2#!#sp_renamedb_login2#!#sp_renamedb_database1 @@ -87,6 +88,7 @@ sp_renamedb_database2_db_accessadmin#!##!#db_accessadmin#!#sp_renamedb_database2 sp_renamedb_database2_db_datareader#!##!#db_datareader#!#sp_renamedb_database2 sp_renamedb_database2_db_datawriter#!##!#db_datawriter#!#sp_renamedb_database2 sp_renamedb_database2_db_owner#!##!#db_owner#!#sp_renamedb_database2 +sp_renamedb_database2_db_securityadmin#!##!#db_securityadmin#!#sp_renamedb_database2 sp_renamedb_database2_dbo#!##!#dbo#!#sp_renamedb_database2 sp_renamedb_database2_guest#!##!#guest#!#sp_renamedb_database2 sp_renamedb_database2_sp_renamedb_login2#!#sp_renamedb_login2#!#sp_renamedb_login2#!#sp_renamedb_database2 @@ -205,6 +207,7 @@ sp_renamedb_thisnewdatabasename115699cc11f7805d9b9b640d6455580c#!##!#dbo#!#sp_re sp_renamedb_thisnewdatabasename2a476218bfa8dba9ac86fb898b11e9a5#!##!#db_datawriter#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd sp_renamedb_thisnewdatabasename7052c471c798d0b08c69f719bcd607d7#!##!#db_datareader#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd sp_renamedb_thisnewdatabasenameb0dffbb56deab7ad4e684df689419c65#!##!#db_owner#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd +sp_renamedb_thisnewdatabasenameda6915c331b2fe3a4c4e33126c0366c1#!##!#db_securityadmin#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd sp_renamedb_thisnewdatabasenamedeb7cafbbedd23f312d90e7c10a60901#!##!#guest#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd sp_renamedb_thisnewdatabasenameeeb9e8f522c23281503d418ce3640572#!##!#db_accessadmin#!#sp_renamedb_thisnewdatabasename738bbb14cb857db43c693446c049f0bd ~~END~~ diff --git a/test/JDBC/expected/datareader_datawriter.out b/test/JDBC/expected/datareader_datawriter.out index 8fe304b2bbc..ddc726e3b2d 100644 --- a/test/JDBC/expected/datareader_datawriter.out +++ b/test/JDBC/expected/datareader_datawriter.out @@ -284,7 +284,7 @@ go -- Insert the results of sp_helprole into the temporary table INSERT INTO #UserRoles EXEC sp_helprole; go -~~ROW COUNT: 5~~ +~~ROW COUNT: 6~~ -- Select the desired fields from the temporary table SELECT RoleName, IsAppRole FROM #UserRoles WHERE RoleName IN ('db_datareader', 'db_datawriter'); diff --git a/test/JDBC/expected/db_accessadmin-vu-verify.out b/test/JDBC/expected/db_accessadmin-vu-verify.out index e3075155dd6..b5fc51976f5 100644 --- a/test/JDBC/expected/db_accessadmin-vu-verify.out +++ b/test/JDBC/expected/db_accessadmin-vu-verify.out @@ -588,6 +588,29 @@ GO -- terminate-tsql-conn user=babel_5136_db_accessadmin_l1 password=12345678 database=babel_5136 -- tsql +USE babel_5136 +GO +CREATE SCHEMA BABEL5119_schema; +GO + +-- test for BABEL-5294 +SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) + FROM ( + SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() + ) AS a + JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) + WHERE u.database_name = 'babel_5136' + ORDER BY u.orig_username; +GO +~~START~~ +nvarchar#!#varchar +db_accessadmin#!#=C +db_securityadmin#!#=C +dbo#!#=CTc +~~END~~ + +USE master +GO DROP DATABASE babel_5136 GO -- terminate-tsql-conn diff --git a/test/JDBC/expected/db_securityadmin-vu-cleanup.out b/test/JDBC/expected/db_securityadmin-vu-cleanup.out new file mode 100644 index 00000000000..94345389f4c --- /dev/null +++ b/test/JDBC/expected/db_securityadmin-vu-cleanup.out @@ -0,0 +1,43 @@ +-- tsql +USE master +GO +DROP DATABASE IF EXISTS babel_5135_db1; +GO +DROP ROLE babel_5135_r1; +GO +DROP LOGIN babel_5135_l2 +GO +DROP USER babel_5135_dbsecadmin_u1 +GO +DROP LOGIN babel_5135_dbsecadmin_l1 +GO +DROP ROLE babel_5135_dbsecadmin_r1 +GO +DROP TABLE babel_5135_schema1.babel_5135_t1; +GO +DROP VIEW babel_5135_schema1.babel_5135_v1; +GO +DROP PROCEDURE babel_5135_schema1.babel_5135_p1; +GO +DROP FUNCTION babel_5135_schema1.babel_5135_f1(); +GO +DROP FUNCTION babel_5135_schema1.babel_5135_tvf1(); +GO +DROP PROCEDURE babel_5135_roleop_proc1; +GO +DROP PROCEDURE babel_5135_roleop_proc2; +GO +DROP PROCEDURE babel_5135_roleop_proc3; +GO +DROP PROCEDURE babel_5135_schemaop_proc1; +GO +DROP PROCEDURE babel_5135_grantop_proc1, babel_5135_revokeop_proc1; +GO +DROP SCHEMA babel_5135_schema1; +GO +DROP USER babel_5135_u1; +GO +DROP LOGIN babel_5135_l1; +GO +DROP VIEW babel_5135_show_role_mem; +GO diff --git a/test/JDBC/expected/db_securityadmin-vu-prepare.out b/test/JDBC/expected/db_securityadmin-vu-prepare.out new file mode 100644 index 00000000000..d1c19b8dd44 --- /dev/null +++ b/test/JDBC/expected/db_securityadmin-vu-prepare.out @@ -0,0 +1,108 @@ +-- tsql +create login babel_5135_l1 with password='12345678'; +GO + +create user babel_5135_u1 for login babel_5135_l1; +GO + +create role babel_5135_r1; +GO + +create login babel_5135_l2 with password='12345678'; +GO + +create login babel_5135_dbsecadmin_l1 with password='12345678'; +GO + +create user babel_5135_dbsecadmin_u1 for login babel_5135_dbsecadmin_l1; +GO + +create role babel_5135_dbsecadmin_r1; +GO + +create schema babel_5135_schema1; +GO + +create table babel_5135_schema1.babel_5135_t1(a int, b int); +GO + +create view babel_5135_schema1.babel_5135_v1 as select 1; +GO + +CREATE PROC babel_5135_schema1.babel_5135_p1 AS SELECT 1 +GO + +CREATE FUNCTION babel_5135_schema1.babel_5135_f1() RETURNS INT AS BEGIN return 1; END +GO + +CREATE FUNCTION babel_5135_schema1.babel_5135_tvf1() RETURNS TABLE AS RETURN (SELECT a, b FROM babel_5135_schema1.babel_5135_t1); +GO + +CREATE VIEW babel_5135_show_role_mem AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.database_role_members AS db_role_mems +INNER JOIN sys.database_principals AS roles + ON db_role_mems.role_principal_id = roles.principal_id +INNER JOIN sys.database_principals AS members + ON db_role_mems.member_principal_id = members.principal_id order by MemberPrincipalName; +GO + +CREATE PROCEDURE babel_5135_roleop_proc1 AS BEGIN CREATE ROLE babel_5135_role2; ALTER ROLE babel_5135_role2 WITH NAME = babel_5135_role3; DROP ROLE babel_5135_role3; END +GO +CREATE PROCEDURE babel_5135_roleop_proc2 AS BEGIN ALTER ROLE babel_5135_r1 ADD MEMBER babel_5135_u1; END +GO +CREATE PROCEDURE babel_5135_roleop_proc3 AS BEGIN ALTER ROLE babel_5135_r1 DROP MEMBER babel_5135_u1; END +GO +CREATE PROCEDURE babel_5135_schemaop_proc1 AS BEGIN CREATE SCHEMA babel_5135_sch11; END +GO +CREATE PROCEDURE babel_5135_grantop_proc1 AS BEGIN +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +END +GO +CREATE PROCEDURE babel_5135_revokeop_proc1 AS BEGIN +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +END +GO + +GRANT EXECUTE ON babel_5135_roleop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_roleop_proc2 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_roleop_proc3 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_schemaop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_grantop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_revokeop_proc1 TO PUBLIC; +GO + +create database babel_5135_db1 +GO + +USE babel_5135_db1; +GO + +create user babel_5135_u1 for login babel_5135_l1; +GO + +CREATE VIEW babel_5135_show_role_mem AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.database_role_members AS db_role_mems +INNER JOIN sys.database_principals AS roles + ON db_role_mems.role_principal_id = roles.principal_id +INNER JOIN sys.database_principals AS members + ON db_role_mems.member_principal_id = members.principal_id order by MemberPrincipalName; +GO diff --git a/test/JDBC/expected/db_securityadmin-vu-verify.out b/test/JDBC/expected/db_securityadmin-vu-verify.out new file mode 100644 index 00000000000..33a1c7defb5 --- /dev/null +++ b/test/JDBC/expected/db_securityadmin-vu-verify.out @@ -0,0 +1,1317 @@ +-- tsql +-- bbf dump does not dump password so reset the password +ALTER LOGIN babel_5135_l1 WITH PASSWORD='12345678'; +GO + +ALTER LOGIN babel_5135_l2 WITH PASSWORD='12345678'; +GO + +ALTER LOGIN babel_5135_dbsecadmin_l1 WITH PASSWORD='12345678'; +GO + +-- tsql +-- CASE 1 Allowed syntaxes to modify the membership of db_securityadmin + -- CASE 1.1 Validate ALTER ROLE ... ADD/DROP MEMBER + -- CASE 1.2 Validate sp_addrolemember + -- CASE 1.3 Test inside database with truncated name +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_r1; +GO + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_r1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +db_securityadmin#!#babel_5135_r1 +db_securityadmin#!#babel_5135_u1 +~~END~~ + + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_u1; +GO + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_r1; +GO + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_r1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +~~END~~ + + +-- CASE 1.3 Test inside database with truncated name +USE babel_5135_db1; +GO + +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +db_securityadmin#!#babel_5135_u1 +~~END~~ + + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_u1; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +~~END~~ + + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +db_securityadmin#!#babel_5135_u1 +~~END~~ + + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#varchar +~~END~~ + + +USE master; +GO + +-- tsql +-- CASE 2 - Only members of db_owner should be able to modify the membership of db_securityadmin + -- [already covered by CASE 1] CASE 2.1 - Verify members of db_owner can modify the membership + -- CASE 2.2 - Verify that members of db_securityadmin itself can't modify it's own membership +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_dbsecadmin_u1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- it should fail +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot alter the role 'db_securityadmin', because it does not exist or you do not have permission.)~~ + + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_dbsecadmin_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot alter the role 'db_securityadmin', because it does not exist or you do not have permission.)~~ + + +-- tsql +-- CASE 3 - Able to manage database roles + -- CASE 3.1 - CREATE/ALTER/DROP ROLE + -- CASE 3.2 - ADD/DROP the membership of user-defined database roles should be allowed + -- CASE 3.3 - ADD/DROP the membership of system-defined database roles should be blocked + -- CASE 3.4 - CREATE/ALTER/DROP USER should not be Allowed +-- role created by another user, to test alter/drop on it +CREATE ROLE babel_5135_role1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +CREATE ROLE babel_5135_role2; +GO + +ALTER ROLE babel_5135_role2 WITH NAME = babel_5135_role3; +GO + +DROP ROLE babel_5135_role3; +GO + +ALTER ROLE babel_5135_role1 WITH NAME = babel_5135_role4; +GO + +DROP ROLE babel_5135_role4; +GO + +-- create/alter/drop role inside procedure +-- execution should be succeeded with no error +EXEC babel_5135_roleop_proc1; +GO + +-- CASE 3.2 - ADD/DROP the membership of user-defined database roles +ALTER ROLE babel_5135_r1 ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE babel_5135_r1 DROP MEMBER babel_5135_u1; +GO + +-- alter role add member inside procedure +-- execution should be succeeded with no error +-- Add +EXEC babel_5135_roleop_proc2; +GO + +-- Drop +EXEC babel_5135_roleop_proc3; +GO + +-- CASE 3.3 - ADD/DROP the membership of system-defined database roles should be blocked +ALTER ROLE db_accessadmin ADD MEMBER babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot alter the role 'db_accessadmin', because it does not exist or you do not have permission.)~~ + + +ALTER ROLE db_owner ADD MEMBER babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Adding members to db_owner is not currently supported in Babelfish)~~ + + +-- CASE 3.4 -- CREATE/ALTER/DROP USER should fail +CREATE USER babel_5135_user1 FOR LOGIN babel_5135_l2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User does not have permission to perform this action.)~~ + + +ALTER USER babel_5135_u1 WITH NAME = babel_5135_dbsecadmin_u2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Current user does not have privileges to change user name)~~ + + +ALTER USER babel_5135_u1 WITH DEFAULT_SCHEMA=dbo; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Current user does not have privileges to change schema)~~ + + +DROP USER babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot drop the user 'babel_5135_u1', because it does not exist or you do not have permission.)~~ + + +-- CASE 4 - CREATE SCHEMA should be allowed +CREATE SCHEMA babel_5135_sch1; +GO + +CREATE SCHEMA babel_5135_sch2 AUTHORIZATION babel_5135_u1; +GO + +SELECT name, sys.user_name(principal_id) FROM sys.schemas WHERE name IN ('babel_5135_sch1','babel_5135_sch2') ORDER BY name; +GO +~~START~~ +varchar#!#nvarchar +babel_5135_sch1#!#babel_5135_dbsecadmin_u1 +babel_5135_sch2#!#babel_5135_u1 +~~END~~ + + +-- tsql +-- granting db_securityadmin to guest and create schema +alter role db_securityadmin add member guest; +GO + +-- tsql user=babel_5135_l2 password=12345678 +select current_user; +GO +~~START~~ +varchar +guest +~~END~~ + + +CREATE SCHEMA babel_5135_sch3; +GO + +SELECT name, sys.user_name(principal_id) FROM sys.schemas WHERE name LIKE 'babel_5135_sch3' ORDER BY name; +GO +~~START~~ +varchar#!#nvarchar +babel_5135_sch3#!#guest +~~END~~ + + +DROP SCHEMA babel_5135_sch3; +GO + +-- tsql +alter role db_securityadmin DROP member guest; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- schema creation inside procedure +-- execution should be succeeded with no error +EXEC babel_5135_schemaop_proc1; +GO + +DROP SCHEMA babel_5135_sch11; +GO + +-- ALTER/DROP of unowned schema should not be allowed +-- NOTE: Add testcase when supported +ALTER SCHEMA babel_5135_schema1 TRANSFER t33144; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'ALTER SCHEMA' is not currently supported in Babelfish)~~ + + +DROP SCHEMA babel_5135_schema1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: must be owner of schema master_babel_5135_schema1)~~ + + +DROP SCHEMA babel_5135_sch1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + +DROP SCHEMA babel_5135_sch2; +GO + +-- CASE 5 - GRANT/REVOKE management of permissions + -- CASE 5.1 - Validate GRANT/REVOKE of object/schema privileges + -- CASE 5.2 - Validate members of db_securityadmin can not actually access given objects + -- CASE 5.3 - Validate that after GRANT/REVOKE, objectowner/dbo can execute REVOKE/GRANT respectively + -- CASE 5.4 - Grant/Revoke should not be allowed for show shared schema or any other database's schema +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_v1)~~ + + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_p1)~~ + + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_5135_v1)~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_5135_p1)~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_5135_v1)~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_5135_p1)~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- Testing GRANT inside procedure +EXEC babel_5135_grantop_proc1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~START~~ +int +0 +~~END~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~START~~ +int +1 +~~END~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~START~~ +int +1 +~~END~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~START~~ +int#!#int +~~END~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- Testing revokes inside procedure +EXEC babel_5135_revokeop_proc1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_5135_v1)~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_5135_p1)~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +GRANT SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 TO babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~START~~ +int +0 +~~END~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~START~~ +int +1 +~~END~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~START~~ +int +1 +~~END~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~START~~ +int#!#int +~~END~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 FROM babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_5135_v1)~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_5135_p1)~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- CASE 5.2 - Validate members of db_securityadmin can not actually access given objects +SELECT current_user; +GO +~~START~~ +varchar +babel_5135_dbsecadmin_u1 +~~END~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_t1)~~ + + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for view babel_5135_v1)~~ + + +EXEC babel_5135_schema1.babel_5135_p1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for procedure babel_5135_p1)~~ + + +SELECT babel_5135_schema1.babel_5135_f1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_f1)~~ + + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for function babel_5135_tvf1)~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- CASE 5.3 - Validate that after GRANT/REVOKE, objectowner/dbo can execute REVOKE/GRANT respectively +-- execute GRANT via db_securityadmin member and REVOKE it with object owner +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO + +-- tsql +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- execute GRANT as objectowner/dbo +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- CASE 5.4 - Grant/Revoke should not be allowed for show shared schema or any other database's schema +-- Following error is misleading, will be fixed separately +GRANT SELECT ON sys.database_principals TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Could find logical schema name for: "sys")~~ + + +REVOKE SELECT ON sys.database_principals FROM babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Could find logical schema name for: "sys")~~ + + +GRANT SELECT ON pg_catalog.pg_namespace TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Could find logical schema name for: "pg_catalog")~~ + + +REVOKE SELECT ON pg_catalog.pg_namespace FROM babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Could find logical schema name for: "pg_catalog")~~ + + +REVOKE SELECT ON babel_5135_db1.dbo.babel_5135_show_role_mem TO babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_show_role_mem)~~ + + +REVOKE SELECT ON babel_5135_db1.dbo.babel_5135_show_role_mem FROM babel_5135_u1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: permission denied for table babel_5135_show_role_mem)~~ + + +-- tsql +-- CASE 6 - is_member() / is_rolemember() testcases +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO +~~START~~ +int#!#int +0#!#1 +~~END~~ + + +SELECT is_rolemember('db_securityadmin', 'dbo'); +GO +~~START~~ +int +1 +~~END~~ + + +SELECT is_rolemember('db_securityadmin', 'db_owner'); +GO +~~START~~ +int +0 +~~END~~ + + +SELECT is_rolemember('db_securityadmin', 'db_accessadmin'); +GO +~~START~~ +int +0 +~~END~~ + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO +~~START~~ +int#!#int +1#!#1 +~~END~~ + + +-- tsql +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_dbsecadmin_u1'; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO +~~START~~ +int#!#int +0#!#0 +~~END~~ + + +-- tsql +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_dbsecadmin_u1'; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO +~~START~~ +int#!#int +1#!#1 +~~END~~ + + + +-- tsql +-- CASE 7 - system procedures + -- CASE 7.1 - sp_helpdbfixedrole testcase are covered in respective test Test-sp_helpdbfixedrole file + -- CASE 7.2 - sp_helpuser + -- CASE 7.3 - sp_helprole + -- CASE 7.4 - sp_helprolemember +-- test for helpuser +CREATE TABLE temp_sp_helpuser(RoleName sys.sysname, Role_id int, +Users_in_role sys.sysname, UserID int); +GO + +GRANT INSERT,SELECT ON temp_sp_helpuser TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helpuser(RoleName, Role_id, Users_in_role, UserID) EXEC sp_helpuser 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT Rolename, sys.user_name(Role_id), Users_in_role, sys.user_name(UserID) FROM temp_sp_helpuser +WHERE Rolename = 'db_securityadmin' ORDER BY Users_in_role; +GO +~~START~~ +varchar#!#nvarchar#!#varchar#!#nvarchar +db_securityadmin#!#db_securityadmin#!#babel_5135_dbsecadmin_u1#!#babel_5135_dbsecadmin_u1 +~~END~~ + + +-- tsql +TRUNCATE TABLE temp_sp_helpuser; +GO + +-- tsql +INSERT INTO temp_sp_helpuser(RoleName, Role_id, Users_in_role, UserID) EXEC sp_helpuser 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT Rolename, sys.user_name(Role_id), Users_in_role, sys.user_name(UserID) FROM temp_sp_helpuser +WHERE Rolename = 'db_securityadmin' ORDER BY Users_in_role; +GO +~~START~~ +varchar#!#nvarchar#!#varchar#!#nvarchar +db_securityadmin#!#db_securityadmin#!#babel_5135_dbsecadmin_u1#!#babel_5135_dbsecadmin_u1 +~~END~~ + + +-- tsql +DROP TABLE temp_sp_helpuser; +GO + +-- test for sp_helprole +CREATE TABLE temp_sp_helprole(RoleName sys.sysname, RoleId int, IsAppRole int); +GO + +GRANT INSERT,SELECT ON temp_sp_helprole TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helprole(RoleName, RoleId, IsAppRole) EXEC sp_helprole 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT RoleName, sys.user_name(RoleId), IsAppRole FROM temp_sp_helprole +WHERE RoleName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#nvarchar#!#int +db_securityadmin#!#db_securityadmin#!#0 +~~END~~ + + +-- tsql +TRUNCATE TABLE temp_sp_helprole; +GO + +-- tsql +INSERT INTO temp_sp_helprole(RoleName, RoleId, IsAppRole) EXEC sp_helprole 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT RoleName, sys.user_name(RoleId), IsAppRole FROM temp_sp_helprole +WHERE RoleName = 'db_securityadmin'; +GO +~~START~~ +varchar#!#nvarchar#!#int +db_securityadmin#!#db_securityadmin#!#0 +~~END~~ + + +-- tsql +DROP TABLE temp_sp_helprole; +GO + +-- test for temp_sp_helprolemember +CREATE TABLE temp_sp_helprolemember(DbRole sys.sysname, MemberName sys.sysname, MemberSID SYS.VARBINARY(85)); +GO + +GRANT INSERT,SELECT ON temp_sp_helprolemember TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helprolemember(DbRole, MemberName, MemberSID) EXEC sp_helprolemember 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT DbRole, MemberName FROM temp_sp_helprolemember +WHERE DbRole = 'db_securityadmin' ORDER BY MemberName; +GO +~~START~~ +varchar#!#varchar +db_securityadmin#!#babel_5135_dbsecadmin_u1 +~~END~~ + + +-- tsql +TRUNCATE TABLE temp_sp_helprolemember; +GO + +-- tsql +INSERT INTO temp_sp_helprolemember(DbRole, MemberName, MemberSID) EXEC sp_helprolemember 'db_securityadmin'; +GO +~~ROW COUNT: 1~~ + + +SELECT DbRole, MemberName FROM temp_sp_helprolemember +WHERE DbRole = 'db_securityadmin' ORDER BY MemberName; +GO +~~START~~ +varchar#!#varchar +db_securityadmin#!#babel_5135_dbsecadmin_u1 +~~END~~ + + +-- tsql +DROP TABLE temp_sp_helprolemember; +GO + +-- CASE 8 +USE babel_5135_db1; +GO + +SELECT name, type, type_desc, default_schema_name, is_fixed_role, authentication_type_desc FROM sys.database_principals WHERE NAME = 'db_securityadmin'; +GO +~~START~~ +varchar#!#char#!#nvarchar#!#varchar#!#bit#!#nvarchar +db_securityadmin#!#R#!#DATABASE_ROLE#!##!#1#!# +~~END~~ + + +USE master; +GO + +-- tsql +-- CASE 9 - Restrictions +-- normal tsql login +CREATE LOGIN db_securityadmin_restrictions_login WITH password = '12345678'; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER db_securityadmin_restrictions_login; +GO + +-- psql +-- normal PG user +CREATE USER db_securityadmin_restrictions_pg_user WITH LOGIN CREATEROLE CREATEDB PASSWORD '12345678' inherit; +go + +-- tsql user=db_securityadmin_restrictions_login password=12345678 +-- a tsql login should not be able to rename/drop db_securityadmin and grant/revoke on it explicitly from tsql port +ALTER ROLE db_securityadmin WITH NAME = db_securityadmin1; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot alter the user db_securityadmin)~~ + + +DROP ROLE db_securityadmin; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot drop the role 'db_securityadmin'.)~~ + + +GRANT SELECT ON babel_5135_schema1.babel_5135_t1 TO db_securityadmin; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny or revoke permissions to or from special roles.)~~ + + +GRANT SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 TO db_securityadmin; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny or revoke permissions to or from special roles.)~~ + + +REVOKE SELECT ON babel_5135_schema1.babel_5135_t1 FROM db_securityadmin; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny or revoke permissions to or from special roles.)~~ + + +REVOKE SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 FROM db_securityadmin; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Cannot grant, deny or revoke permissions to or from special roles.)~~ + + +-- psql user=db_securityadmin_restrictions_login password=12345678 +-- a tsql login should not be able to alter/grant/drop db_securityadmin from pg port +ALTER ROLE master_db_securityadmin NOCREATEROLE; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin WITH PASSWORD '12345678'; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin VALID UNTIL 'infinity'; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin WITH CONNECTION LIMIT 1; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + + +-- GRANT master_db_securityadmin TO db_securityadmin_restrictions_login; +-- GO +GRANT db_securityadmin_restrictions_login TO master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to grant role "db_securityadmin_restrictions_login" + Detail: Only roles with the ADMIN option on role "db_securityadmin_restrictions_login" may grant this role. + Server SQLState: 42501)~~ + + + +-- REVOKE master_db_securityadmin FROM master_dbo; +-- GO +REVOKE master_dbo FROM master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to revoke role "master_dbo" + Detail: Only roles with the ADMIN option on role "master_dbo" may revoke this role. + Server SQLState: 42501)~~ + + +DROP ROLE master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be dropped or altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +SET SESSION AUTHORIZATION master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to set session authorization + Server SQLState: 42501)~~ + + +SET ROLE master_db_securityadmin; +GO + +-- psql user=db_securityadmin_restrictions_pg_user password=12345678 +-- a normal psql user should not be able to alter/grant/drop db_securityadmin from pg port +ALTER ROLE master_db_securityadmin NOCREATEROLE; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin WITH PASSWORD '12345678'; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin VALID UNTIL 'infinity'; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +ALTER ROLE master_db_securityadmin WITH CONNECTION LIMIT 1; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +GRANT master_db_securityadmin TO db_securityadmin_restrictions_login; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to grant role "master_db_securityadmin" + Detail: Only roles with the ADMIN option on role "master_db_securityadmin" may grant this role. + Server SQLState: 42501)~~ + + +GRANT db_securityadmin_restrictions_login TO master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to grant role "db_securityadmin_restrictions_login" + Detail: Only roles with the ADMIN option on role "db_securityadmin_restrictions_login" may grant this role. + Server SQLState: 42501)~~ + + +REVOKE master_db_securityadmin FROM master_dbo; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to revoke role "master_db_securityadmin" + Detail: Only roles with the ADMIN option on role "master_db_securityadmin" may revoke this role. + Server SQLState: 42501)~~ + + +REVOKE master_dbo FROM master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to revoke role "master_dbo" + Detail: Only roles with the ADMIN option on role "master_dbo" may revoke this role. + Server SQLState: 42501)~~ + + +DROP ROLE master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: Babelfish-created logins/users/roles cannot be dropped or altered outside of a Babelfish session + Server SQLState: 42501)~~ + + +SET SESSION AUTHORIZATION master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to set session authorization + Server SQLState: 42501)~~ + + +SET ROLE master_db_securityadmin; +GO +~~ERROR (Code: 0)~~ + +~~ERROR (Message: ERROR: permission denied to set role "master_db_securityadmin" + Server SQLState: 42501)~~ + + +-- psql +DROP USER db_securityadmin_restrictions_pg_user; +GO + +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'db_securityadmin_restrictions_login' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +GO +~~START~~ +bool +t +t +~~END~~ + + +-- tsql +DROP LOGIN db_securityadmin_restrictions_login; +GO diff --git a/test/JDBC/expected/single_db/BABEL-2403.out b/test/JDBC/expected/single_db/BABEL-2403.out index 2f20395b10c..08d51c04177 100644 --- a/test/JDBC/expected/single_db/BABEL-2403.out +++ b/test/JDBC/expected/single_db/BABEL-2403.out @@ -109,6 +109,12 @@ name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext m text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} name#!#pg_catalog#!#proname#!#{"Rule": " in babelfish_function_ext must also exist in pg_proc"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} @@ -208,6 +214,12 @@ name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext m text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} +name#!#pg_catalog#!#rolname#!#{"Rule": " in babelfish_authid_user_ext must also exist in pg_authid"} +text#!#sys#!#name#!#{"Rule": " in babelfish_authid_user_ext must also exist in babelfish_sysdatabases"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} name#!#pg_catalog#!#proname#!#{"Rule": " in babelfish_function_ext must also exist in pg_proc"} name#!#sys#!#nspname#!#{"Rule": " in babelfish_function_ext must also exist in babelfish_namespace_ext"} diff --git a/test/JDBC/expected/single_db/BABEL-LOGIN-USER-EXT.out b/test/JDBC/expected/single_db/BABEL-LOGIN-USER-EXT.out index 651c14ea950..f01405e747a 100644 --- a/test/JDBC/expected/single_db/BABEL-LOGIN-USER-EXT.out +++ b/test/JDBC/expected/single_db/BABEL-LOGIN-USER-EXT.out @@ -699,23 +699,27 @@ db_accessadmin#!#db_accessadmin#!##!#db1#!# db_datareader#!#db_datareader#!##!#db1#!# db_datawriter#!#db_datawriter#!##!#db1#!# db_owner#!#db_owner#!##!#db1#!# +db_securityadmin#!#db_securityadmin#!##!#db1#!# dbo#!#dbo#!##!#db1#!#dbo master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -883,18 +887,21 @@ master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -948,23 +955,27 @@ db_accessadmin#!##!#db_accessadmin#!#db1#!# db_datareader#!##!#db_datareader#!#db1#!# db_datawriter#!##!#db_datawriter#!#db1#!# db_owner#!##!#db_owner#!#db1#!# +db_securityadmin#!##!#db_securityadmin#!#db1#!# dbo#!##!#dbo#!#db1#!#dbo master_db_accessadmin#!##!#db_accessadmin#!#master#!# master_db_datareader#!##!#db_datareader#!#master#!# master_db_datawriter#!##!#db_datawriter#!#master#!# master_db_owner#!##!#db_owner#!#master#!# +master_db_securityadmin#!##!#db_securityadmin#!#master#!# master_dbo#!##!#dbo#!#master#!#dbo master_guest#!##!#guest#!#master#!#guest msdb_db_accessadmin#!##!#db_accessadmin#!#msdb#!# msdb_db_datareader#!##!#db_datareader#!#msdb#!# msdb_db_datawriter#!##!#db_datawriter#!#msdb#!# msdb_db_owner#!##!#db_owner#!#msdb#!# +msdb_db_securityadmin#!##!#db_securityadmin#!#msdb#!# msdb_dbo#!##!#dbo#!#msdb#!#dbo msdb_guest#!##!#guest#!#msdb#!#guest tempdb_db_accessadmin#!##!#db_accessadmin#!#tempdb#!# tempdb_db_datareader#!##!#db_datareader#!#tempdb#!# tempdb_db_datawriter#!##!#db_datawriter#!#tempdb#!# tempdb_db_owner#!##!#db_owner#!#tempdb#!# +tempdb_db_securityadmin#!##!#db_securityadmin#!#tempdb#!# tempdb_dbo#!##!#dbo#!#tempdb#!#dbo tempdb_guest#!##!#guest#!#tempdb#!#guest ~~END~~ @@ -982,6 +993,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# @@ -1016,6 +1028,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# @@ -1157,18 +1170,21 @@ master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -1191,18 +1207,21 @@ master_db_accessadmin#!#db_accessadmin#!##!#master#!# master_db_datareader#!#db_datareader#!##!#master#!# master_db_datawriter#!#db_datawriter#!##!#master#!# master_db_owner#!#db_owner#!##!#master#!# +master_db_securityadmin#!#db_securityadmin#!##!#master#!# master_dbo#!#dbo#!##!#master#!#dbo master_guest#!#guest#!##!#master#!#guest msdb_db_accessadmin#!#db_accessadmin#!##!#msdb#!# msdb_db_datareader#!#db_datareader#!##!#msdb#!# msdb_db_datawriter#!#db_datawriter#!##!#msdb#!# msdb_db_owner#!#db_owner#!##!#msdb#!# +msdb_db_securityadmin#!#db_securityadmin#!##!#msdb#!# msdb_dbo#!#dbo#!##!#msdb#!#dbo msdb_guest#!#guest#!##!#msdb#!#guest tempdb_db_accessadmin#!#db_accessadmin#!##!#tempdb#!# tempdb_db_datareader#!#db_datareader#!##!#tempdb#!# tempdb_db_datawriter#!#db_datawriter#!##!#tempdb#!# tempdb_db_owner#!#db_owner#!##!#tempdb#!# +tempdb_db_securityadmin#!#db_securityadmin#!##!#tempdb#!# tempdb_dbo#!#dbo#!##!#tempdb#!#dbo tempdb_guest#!#guest#!##!#tempdb#!#guest ~~END~~ @@ -1495,6 +1514,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1515,6 +1535,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1534,6 +1555,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA @@ -1552,6 +1574,7 @@ db_accessadmin db_datareader db_datawriter db_owner +db_securityadmin dbo guest INFORMATION_SCHEMA diff --git a/test/JDBC/expected/single_db/BABEL-USER.out b/test/JDBC/expected/single_db/BABEL-USER.out index c3ce6672b62..a38500e1d7f 100644 --- a/test/JDBC/expected/single_db/BABEL-USER.out +++ b/test/JDBC/expected/single_db/BABEL-USER.out @@ -54,23 +54,27 @@ db_accessadmin#!##!#db_accessadmin#!#db1#!# db_datareader#!##!#db_datareader#!#db1#!# db_datawriter#!##!#db_datawriter#!#db1#!# db_owner#!##!#db_owner#!#db1#!# +db_securityadmin#!##!#db_securityadmin#!#db1#!# dbo#!##!#dbo#!#db1#!#dbo master_db_accessadmin#!##!#db_accessadmin#!#master#!# master_db_datareader#!##!#db_datareader#!#master#!# master_db_datawriter#!##!#db_datawriter#!#master#!# master_db_owner#!##!#db_owner#!#master#!# +master_db_securityadmin#!##!#db_securityadmin#!#master#!# master_dbo#!##!#dbo#!#master#!#dbo master_guest#!##!#guest#!#master#!#guest msdb_db_accessadmin#!##!#db_accessadmin#!#msdb#!# msdb_db_datareader#!##!#db_datareader#!#msdb#!# msdb_db_datawriter#!##!#db_datawriter#!#msdb#!# msdb_db_owner#!##!#db_owner#!#msdb#!# +msdb_db_securityadmin#!##!#db_securityadmin#!#msdb#!# msdb_dbo#!##!#dbo#!#msdb#!#dbo msdb_guest#!##!#guest#!#msdb#!#guest tempdb_db_accessadmin#!##!#db_accessadmin#!#tempdb#!# tempdb_db_datareader#!##!#db_datareader#!#tempdb#!# tempdb_db_datawriter#!##!#db_datawriter#!#tempdb#!# tempdb_db_owner#!##!#db_owner#!#tempdb#!# +tempdb_db_securityadmin#!##!#db_securityadmin#!#tempdb#!# tempdb_dbo#!##!#dbo#!#tempdb#!#dbo tempdb_guest#!##!#guest#!#tempdb#!#guest ~~END~~ @@ -88,6 +92,7 @@ db_accessadmin#!# db_datareader#!# db_datawriter#!# db_owner#!# +db_securityadmin#!# INFORMATION_SCHEMA#!# public#!# sys#!# diff --git a/test/JDBC/expected/single_db/Test_rename_db_single-db.out b/test/JDBC/expected/single_db/Test_rename_db_single-db.out index 5a0c7abc7b9..31fd69b3cec 100644 --- a/test/JDBC/expected/single_db/Test_rename_db_single-db.out +++ b/test/JDBC/expected/single_db/Test_rename_db_single-db.out @@ -36,6 +36,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 db_datareader#!##!#db_datareader#!#rename_db_database1 db_datawriter#!##!#db_datawriter#!#rename_db_database1 db_owner#!##!#db_owner#!#rename_db_database1 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -87,6 +88,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 db_datareader#!##!#db_datareader#!#rename_db_database2 db_datawriter#!##!#db_datawriter#!#rename_db_database2 db_owner#!##!#db_owner#!#rename_db_database2 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -138,6 +140,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 db_datareader#!##!#db_datareader#!#rename_db_database1 db_datawriter#!##!#db_datawriter#!#rename_db_database1 db_owner#!##!#db_owner#!#rename_db_database1 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -189,6 +192,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 db_datareader#!##!#db_datareader#!#rename_db_database2 db_datawriter#!##!#db_datawriter#!#rename_db_database2 db_owner#!##!#db_owner#!#rename_db_database2 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -252,6 +256,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 db_datareader#!##!#db_datareader#!#rename_db_database1 db_datawriter#!##!#db_datawriter#!#rename_db_database1 db_owner#!##!#db_owner#!#rename_db_database1 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -303,6 +308,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 db_datareader#!##!#db_datareader#!#rename_db_database2 db_datawriter#!##!#db_datawriter#!#rename_db_database2 db_owner#!##!#db_owner#!#rename_db_database2 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 @@ -354,6 +360,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database1 db_datareader#!##!#db_datareader#!#rename_db_database1 db_datawriter#!##!#db_datawriter#!#rename_db_database1 db_owner#!##!#db_owner#!#rename_db_database1 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database1 dbo#!##!#dbo#!#rename_db_database1 rename_db_database1_guest#!##!#guest#!#rename_db_database1 rename_db_database1_rename_db_role1#!##!#rename_db_role1#!#rename_db_database1 @@ -405,6 +412,7 @@ db_accessadmin#!##!#db_accessadmin#!#rename_db_database2 db_datareader#!##!#db_datareader#!#rename_db_database2 db_datawriter#!##!#db_datawriter#!#rename_db_database2 db_owner#!##!#db_owner#!#rename_db_database2 +db_securityadmin#!##!#db_securityadmin#!#rename_db_database2 dbo#!##!#dbo#!#rename_db_database2 rename_db_database2_guest#!##!#guest#!#rename_db_database2 rename_db_database2_rename_db_role1#!##!#rename_db_role1#!#rename_db_database2 diff --git a/test/JDBC/expected/single_db/datareader_datawriter.out b/test/JDBC/expected/single_db/datareader_datawriter.out index 570128b3df1..4a0dcfa4f5b 100644 --- a/test/JDBC/expected/single_db/datareader_datawriter.out +++ b/test/JDBC/expected/single_db/datareader_datawriter.out @@ -284,7 +284,7 @@ go -- Insert the results of sp_helprole into the temporary table INSERT INTO #UserRoles EXEC sp_helprole; go -~~ROW COUNT: 5~~ +~~ROW COUNT: 6~~ -- Select the desired fields from the temporary table SELECT RoleName, IsAppRole FROM #UserRoles WHERE RoleName IN ('db_datareader', 'db_datawriter'); diff --git a/test/JDBC/input/BABEL-5119-vu-verify.mix b/test/JDBC/input/BABEL-5119-vu-verify.mix index 00c10b06139..1532903a149 100644 --- a/test/JDBC/input/BABEL-5119-vu-verify.mix +++ b/test/JDBC/input/BABEL-5119-vu-verify.mix @@ -364,17 +364,3 @@ GO INSERT INTO BABEL5119_t1 VALUES(1) GO -- terminate-tsql-conn user=login_babel5119_2 password=12345678 - --- tsql database=BABEL5119_db -CREATE SCHEMA BABEL5119_schema; -GO - -SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) - FROM ( - SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() - ) AS a - JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) - WHERE u.database_name = 'BABEL5119_db' - ORDER BY u.orig_username; -GO --- terminate-tsql-conn database=BABEL5119_db \ No newline at end of file diff --git a/test/JDBC/input/BABEL-5119_before_16_5-vu-verify.mix b/test/JDBC/input/BABEL-5119_before_16_5-vu-verify.mix index 00c10b06139..1532903a149 100644 --- a/test/JDBC/input/BABEL-5119_before_16_5-vu-verify.mix +++ b/test/JDBC/input/BABEL-5119_before_16_5-vu-verify.mix @@ -364,17 +364,3 @@ GO INSERT INTO BABEL5119_t1 VALUES(1) GO -- terminate-tsql-conn user=login_babel5119_2 password=12345678 - --- tsql database=BABEL5119_db -CREATE SCHEMA BABEL5119_schema; -GO - -SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) - FROM ( - SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() - ) AS a - JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) - WHERE u.database_name = 'BABEL5119_db' - ORDER BY u.orig_username; -GO --- terminate-tsql-conn database=BABEL5119_db \ No newline at end of file diff --git a/test/JDBC/input/BABEL-SP_COLUMN_PRIVILEGES.mix b/test/JDBC/input/BABEL-SP_COLUMN_PRIVILEGES.mix index 992ddd6bf95..dae08b913fc 100644 --- a/test/JDBC/input/BABEL-SP_COLUMN_PRIVILEGES.mix +++ b/test/JDBC/input/BABEL-SP_COLUMN_PRIVILEGES.mix @@ -1,5 +1,5 @@ --- sla 20000 --- sla_for_parallel_query_enforced 20000 +-- sla 60000 +-- sla_for_parallel_query_enforced 60000 -- tsql CREATE DATABASE db1 GO diff --git a/test/JDBC/input/db_accessadmin-vu-verify.mix b/test/JDBC/input/db_accessadmin-vu-verify.mix index 353e1fb1231..c9fadfc3b07 100644 --- a/test/JDBC/input/db_accessadmin-vu-verify.mix +++ b/test/JDBC/input/db_accessadmin-vu-verify.mix @@ -278,6 +278,22 @@ GO -- terminate-tsql-conn user=babel_5136_db_accessadmin_l1 password=12345678 database=babel_5136 -- tsql +USE babel_5136 +GO +CREATE SCHEMA BABEL5119_schema; +GO + +-- test for BABEL-5294 +SELECT u.orig_username, SUBSTRING(a.datacl, strpos(a.datacl, '='), strpos(a.datacl, '/') - strpos(a.datacl, '=')) + FROM ( + SELECT CAST(unnest(datacl) AS TEXT) AS datacl FROM pg_database WHERE datname = CURRENT_DATABASE() + ) AS a + JOIN sys.babelfish_authid_user_ext u ON (left(datacl, charindex('=', datacl) - 1) = u.rolname) + WHERE u.database_name = 'babel_5136' + ORDER BY u.orig_username; +GO +USE master +GO DROP DATABASE babel_5136 GO -- terminate-tsql-conn diff --git a/test/JDBC/input/ownership/db_securityadmin-vu-cleanup.mix b/test/JDBC/input/ownership/db_securityadmin-vu-cleanup.mix new file mode 100644 index 00000000000..94345389f4c --- /dev/null +++ b/test/JDBC/input/ownership/db_securityadmin-vu-cleanup.mix @@ -0,0 +1,43 @@ +-- tsql +USE master +GO +DROP DATABASE IF EXISTS babel_5135_db1; +GO +DROP ROLE babel_5135_r1; +GO +DROP LOGIN babel_5135_l2 +GO +DROP USER babel_5135_dbsecadmin_u1 +GO +DROP LOGIN babel_5135_dbsecadmin_l1 +GO +DROP ROLE babel_5135_dbsecadmin_r1 +GO +DROP TABLE babel_5135_schema1.babel_5135_t1; +GO +DROP VIEW babel_5135_schema1.babel_5135_v1; +GO +DROP PROCEDURE babel_5135_schema1.babel_5135_p1; +GO +DROP FUNCTION babel_5135_schema1.babel_5135_f1(); +GO +DROP FUNCTION babel_5135_schema1.babel_5135_tvf1(); +GO +DROP PROCEDURE babel_5135_roleop_proc1; +GO +DROP PROCEDURE babel_5135_roleop_proc2; +GO +DROP PROCEDURE babel_5135_roleop_proc3; +GO +DROP PROCEDURE babel_5135_schemaop_proc1; +GO +DROP PROCEDURE babel_5135_grantop_proc1, babel_5135_revokeop_proc1; +GO +DROP SCHEMA babel_5135_schema1; +GO +DROP USER babel_5135_u1; +GO +DROP LOGIN babel_5135_l1; +GO +DROP VIEW babel_5135_show_role_mem; +GO diff --git a/test/JDBC/input/ownership/db_securityadmin-vu-prepare.mix b/test/JDBC/input/ownership/db_securityadmin-vu-prepare.mix new file mode 100644 index 00000000000..cb22ffdf6ac --- /dev/null +++ b/test/JDBC/input/ownership/db_securityadmin-vu-prepare.mix @@ -0,0 +1,108 @@ +-- tsql +create login babel_5135_l1 with password='12345678'; +GO + +create user babel_5135_u1 for login babel_5135_l1; +GO + +create role babel_5135_r1; +GO + +create login babel_5135_l2 with password='12345678'; +GO + +create login babel_5135_dbsecadmin_l1 with password='12345678'; +GO + +create user babel_5135_dbsecadmin_u1 for login babel_5135_dbsecadmin_l1; +GO + +create role babel_5135_dbsecadmin_r1; +GO + +create schema babel_5135_schema1; +GO + +create table babel_5135_schema1.babel_5135_t1(a int, b int); +GO + +create view babel_5135_schema1.babel_5135_v1 as select 1; +GO + +CREATE PROC babel_5135_schema1.babel_5135_p1 AS SELECT 1 +GO + +CREATE FUNCTION babel_5135_schema1.babel_5135_f1() RETURNS INT AS BEGIN return 1; END +GO + +CREATE FUNCTION babel_5135_schema1.babel_5135_tvf1() RETURNS TABLE AS RETURN (SELECT a, b FROM babel_5135_schema1.babel_5135_t1); +GO + +CREATE VIEW babel_5135_show_role_mem AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.database_role_members AS db_role_mems +INNER JOIN sys.database_principals AS roles + ON db_role_mems.role_principal_id = roles.principal_id +INNER JOIN sys.database_principals AS members + ON db_role_mems.member_principal_id = members.principal_id order by MemberPrincipalName; +GO + +CREATE PROCEDURE babel_5135_roleop_proc1 AS BEGIN CREATE ROLE babel_5135_role2; ALTER ROLE babel_5135_role2 WITH NAME = babel_5135_role3; DROP ROLE babel_5135_role3; END +GO +CREATE PROCEDURE babel_5135_roleop_proc2 AS BEGIN ALTER ROLE babel_5135_r1 ADD MEMBER babel_5135_u1; END +GO +CREATE PROCEDURE babel_5135_roleop_proc3 AS BEGIN ALTER ROLE babel_5135_r1 DROP MEMBER babel_5135_u1; END +GO +CREATE PROCEDURE babel_5135_schemaop_proc1 AS BEGIN CREATE SCHEMA babel_5135_sch11; END +GO +CREATE PROCEDURE babel_5135_grantop_proc1 AS BEGIN +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +END +GO +CREATE PROCEDURE babel_5135_revokeop_proc1 AS BEGIN +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +END +GO + +GRANT EXECUTE ON babel_5135_roleop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_roleop_proc2 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_roleop_proc3 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_schemaop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_grantop_proc1 TO PUBLIC; +GO +GRANT EXECUTE ON babel_5135_revokeop_proc1 TO PUBLIC; +GO + +create database babel_5135_db1 +GO + +USE babel_5135_db1; +GO + +create user babel_5135_u1 for login babel_5135_l1; +GO + +CREATE VIEW babel_5135_show_role_mem AS +SELECT +roles.name AS RolePrincipalName +, members.name AS MemberPrincipalName +FROM sys.database_role_members AS db_role_mems +INNER JOIN sys.database_principals AS roles + ON db_role_mems.role_principal_id = roles.principal_id +INNER JOIN sys.database_principals AS members + ON db_role_mems.member_principal_id = members.principal_id order by MemberPrincipalName; +GO \ No newline at end of file diff --git a/test/JDBC/input/ownership/db_securityadmin-vu-verify.mix b/test/JDBC/input/ownership/db_securityadmin-vu-verify.mix new file mode 100644 index 00000000000..2f2f15acfc4 --- /dev/null +++ b/test/JDBC/input/ownership/db_securityadmin-vu-verify.mix @@ -0,0 +1,776 @@ +-- tsql +-- bbf dump does not dump password so reset the password +ALTER LOGIN babel_5135_l1 WITH PASSWORD='12345678'; +GO + +ALTER LOGIN babel_5135_l2 WITH PASSWORD='12345678'; +GO + +ALTER LOGIN babel_5135_dbsecadmin_l1 WITH PASSWORD='12345678'; +GO + +-- CASE 1 Allowed syntaxes to modify the membership of db_securityadmin + -- CASE 1.1 Validate ALTER ROLE ... ADD/DROP MEMBER + -- CASE 1.2 Validate sp_addrolemember + -- CASE 1.3 Test inside database with truncated name +-- tsql +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_r1; +GO + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_r1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_u1; +GO + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_r1; +GO + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_r1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +-- CASE 1.3 Test inside database with truncated name +USE babel_5135_db1; +GO + +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_u1; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_u1'; +GO + +SELECT * FROM babel_5135_show_role_mem WHERE RolePrincipalName = 'db_securityadmin'; +GO + +USE master; +GO + +-- CASE 2 - Only members of db_owner should be able to modify the membership of db_securityadmin + -- [already covered by CASE 1] CASE 2.1 - Verify members of db_owner can modify the membership + -- CASE 2.2 - Verify that members of db_securityadmin itself can't modify it's own membership +-- tsql +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_dbsecadmin_u1; +GO + +-- it should fail +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +ALTER ROLE db_securityadmin ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE db_securityadmin DROP MEMBER babel_5135_dbsecadmin_u1; +GO + +-- CASE 3 - Able to manage database roles + -- CASE 3.1 - CREATE/ALTER/DROP ROLE + -- CASE 3.2 - ADD/DROP the membership of user-defined database roles should be allowed + -- CASE 3.3 - ADD/DROP the membership of system-defined database roles should be blocked + -- CASE 3.4 - CREATE/ALTER/DROP USER should not be Allowed +-- role created by another user, to test alter/drop on it +-- tsql +CREATE ROLE babel_5135_role1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +CREATE ROLE babel_5135_role2; +GO + +ALTER ROLE babel_5135_role2 WITH NAME = babel_5135_role3; +GO + +DROP ROLE babel_5135_role3; +GO + +ALTER ROLE babel_5135_role1 WITH NAME = babel_5135_role4; +GO + +DROP ROLE babel_5135_role4; +GO + +-- create/alter/drop role inside procedure +-- execution should be succeeded with no error +EXEC babel_5135_roleop_proc1; +GO + +-- CASE 3.2 - ADD/DROP the membership of user-defined database roles +ALTER ROLE babel_5135_r1 ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE babel_5135_r1 DROP MEMBER babel_5135_u1; +GO + +-- alter role add member inside procedure +-- execution should be succeeded with no error +-- Add +EXEC babel_5135_roleop_proc2; +GO + +-- Drop +EXEC babel_5135_roleop_proc3; +GO + +-- CASE 3.3 - ADD/DROP the membership of system-defined database roles should be blocked +ALTER ROLE db_accessadmin ADD MEMBER babel_5135_u1; +GO + +ALTER ROLE db_owner ADD MEMBER babel_5135_u1; +GO + +-- CASE 3.4 -- CREATE/ALTER/DROP USER should fail +CREATE USER babel_5135_user1 FOR LOGIN babel_5135_l2; +GO + +ALTER USER babel_5135_u1 WITH NAME = babel_5135_dbsecadmin_u2; +GO + +ALTER USER babel_5135_u1 WITH DEFAULT_SCHEMA=dbo; +GO + +DROP USER babel_5135_u1; +GO + +-- CASE 4 - CREATE SCHEMA should be allowed +CREATE SCHEMA babel_5135_sch1; +GO + +CREATE SCHEMA babel_5135_sch2 AUTHORIZATION babel_5135_u1; +GO + +SELECT name, sys.user_name(principal_id) FROM sys.schemas WHERE name IN ('babel_5135_sch1','babel_5135_sch2') ORDER BY name; +GO + +-- granting db_securityadmin to guest and create schema +-- tsql +alter role db_securityadmin add member guest; +GO + +-- tsql user=babel_5135_l2 password=12345678 +select current_user; +GO + +CREATE SCHEMA babel_5135_sch3; +GO + +SELECT name, sys.user_name(principal_id) FROM sys.schemas WHERE name LIKE 'babel_5135_sch3' ORDER BY name; +GO + +DROP SCHEMA babel_5135_sch3; +GO + +-- tsql +alter role db_securityadmin DROP member guest; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- schema creation inside procedure +-- execution should be succeeded with no error +EXEC babel_5135_schemaop_proc1; +GO + +DROP SCHEMA babel_5135_sch11; +GO + +-- ALTER/DROP of unowned schema should not be allowed +-- NOTE: Add testcase when supported +ALTER SCHEMA babel_5135_schema1 TRANSFER t33144; +GO + +DROP SCHEMA babel_5135_schema1; +GO + +DROP SCHEMA babel_5135_sch1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO +DROP SCHEMA babel_5135_sch2; +GO + +-- CASE 5 - GRANT/REVOKE management of permissions + -- CASE 5.1 - Validate GRANT/REVOKE of object/schema privileges + -- CASE 5.2 - Validate members of db_securityadmin can not actually access given objects + -- CASE 5.3 - Validate that after GRANT/REVOKE, objectowner/dbo can execute REVOKE/GRANT respectively + -- CASE 5.4 - Grant/Revoke should not be allowed for show shared schema or any other database's schema +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- Testing GRANT inside procedure +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +EXEC babel_5135_grantop_proc1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- Testing revokes inside procedure +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +EXEC babel_5135_revokeop_proc1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +GRANT SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 TO babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 FROM babel_5135_u1; +GO + +-- tsql user=babel_5135_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- CASE 5.2 - Validate members of db_securityadmin can not actually access given objects +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT current_user; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_t1; +INSERT INTO babel_5135_schema1.babel_5135_t1 VALUES (1,2); +UPDATE babel_5135_schema1.babel_5135_t1 SET a = 2 WHERE a = 1; +DELETE FROM babel_5135_schema1.babel_5135_t1 WHERE a = 2; +GO + +SELECT COUNT(*) FROM babel_5135_schema1.babel_5135_v1; +GO + +EXEC babel_5135_schema1.babel_5135_p1; +GO + +SELECT babel_5135_schema1.babel_5135_f1(); +GO + +SELECT * FROM babel_5135_schema1.babel_5135_tvf1(); +GO + +-- CASE 5.3 - Validate that after GRANT/REVOKE, objectowner/dbo can execute REVOKE/GRANT respectively +-- execute GRANT via db_securityadmin member and REVOKE it with object owner +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO + +-- tsql +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- execute GRANT as objectowner/dbo +GRANT SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 TO babel_5135_u1; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_v1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_p1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_f1 TO babel_5135_u1; +GO + +GRANT EXECUTE ON babel_5135_schema1.babel_5135_tvf1 TO babel_5135_u1; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +REVOKE SELECT, INSERT, UPDATE, DELETE ON babel_5135_schema1.babel_5135_t1 FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_v1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_p1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_f1 FROM babel_5135_u1; +GO + +REVOKE EXECUTE ON babel_5135_schema1.babel_5135_tvf1 FROM babel_5135_u1; +GO + +-- CASE 5.4 - Grant/Revoke should not be allowed for show shared schema or any other database's schema +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +-- Following error is misleading, will be fixed separately +GRANT SELECT ON sys.database_principals TO babel_5135_u1; +GO + +REVOKE SELECT ON sys.database_principals FROM babel_5135_u1; +GO + +GRANT SELECT ON pg_catalog.pg_namespace TO babel_5135_u1; +GO + +REVOKE SELECT ON pg_catalog.pg_namespace FROM babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_db1.dbo.babel_5135_show_role_mem TO babel_5135_u1; +GO + +REVOKE SELECT ON babel_5135_db1.dbo.babel_5135_show_role_mem FROM babel_5135_u1; +GO + +-- CASE 6 - is_member() / is_rolemember() testcases +-- tsql +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO + +SELECT is_rolemember('db_securityadmin', 'dbo'); +GO + +SELECT is_rolemember('db_securityadmin', 'db_owner'); +GO + +SELECT is_rolemember('db_securityadmin', 'db_accessadmin'); +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO + +-- tsql +EXEC sp_droprolemember 'db_securityadmin', 'babel_5135_dbsecadmin_u1'; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO + +-- tsql +EXEC sp_addrolemember 'db_securityadmin', 'babel_5135_dbsecadmin_u1'; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +SELECT is_member('db_securityadmin'), is_rolemember('db_securityadmin'); +GO + +-- CASE 7 - system procedures + -- CASE 7.1 - sp_helpdbfixedrole testcase are covered in respective test Test-sp_helpdbfixedrole file + -- CASE 7.2 - sp_helpuser + -- CASE 7.3 - sp_helprole + -- CASE 7.4 - sp_helprolemember + +-- test for helpuser +-- tsql +CREATE TABLE temp_sp_helpuser(RoleName sys.sysname, Role_id int, +Users_in_role sys.sysname, UserID int); +GO + +GRANT INSERT,SELECT ON temp_sp_helpuser TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helpuser(RoleName, Role_id, Users_in_role, UserID) EXEC sp_helpuser 'db_securityadmin'; +GO + +SELECT Rolename, sys.user_name(Role_id), Users_in_role, sys.user_name(UserID) FROM temp_sp_helpuser +WHERE Rolename = 'db_securityadmin' ORDER BY Users_in_role; +GO + +-- tsql +TRUNCATE TABLE temp_sp_helpuser; +GO + +-- tsql +INSERT INTO temp_sp_helpuser(RoleName, Role_id, Users_in_role, UserID) EXEC sp_helpuser 'db_securityadmin'; +GO + +SELECT Rolename, sys.user_name(Role_id), Users_in_role, sys.user_name(UserID) FROM temp_sp_helpuser +WHERE Rolename = 'db_securityadmin' ORDER BY Users_in_role; +GO + +-- tsql +DROP TABLE temp_sp_helpuser; +GO + +-- test for sp_helprole +CREATE TABLE temp_sp_helprole(RoleName sys.sysname, RoleId int, IsAppRole int); +GO + +GRANT INSERT,SELECT ON temp_sp_helprole TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helprole(RoleName, RoleId, IsAppRole) EXEC sp_helprole 'db_securityadmin'; +GO + +SELECT RoleName, sys.user_name(RoleId), IsAppRole FROM temp_sp_helprole +WHERE RoleName = 'db_securityadmin'; +GO + +-- tsql +TRUNCATE TABLE temp_sp_helprole; +GO + +-- tsql +INSERT INTO temp_sp_helprole(RoleName, RoleId, IsAppRole) EXEC sp_helprole 'db_securityadmin'; +GO + +SELECT RoleName, sys.user_name(RoleId), IsAppRole FROM temp_sp_helprole +WHERE RoleName = 'db_securityadmin'; +GO + +-- tsql +DROP TABLE temp_sp_helprole; +GO + +-- test for temp_sp_helprolemember +CREATE TABLE temp_sp_helprolemember(DbRole sys.sysname, MemberName sys.sysname, MemberSID SYS.VARBINARY(85)); +GO + +GRANT INSERT,SELECT ON temp_sp_helprolemember TO PUBLIC; +GO + +-- tsql user=babel_5135_dbsecadmin_l1 password=12345678 +INSERT INTO temp_sp_helprolemember(DbRole, MemberName, MemberSID) EXEC sp_helprolemember 'db_securityadmin'; +GO + +SELECT DbRole, MemberName FROM temp_sp_helprolemember +WHERE DbRole = 'db_securityadmin' ORDER BY MemberName; +GO + +-- tsql +TRUNCATE TABLE temp_sp_helprolemember; +GO + +-- tsql +INSERT INTO temp_sp_helprolemember(DbRole, MemberName, MemberSID) EXEC sp_helprolemember 'db_securityadmin'; +GO + +SELECT DbRole, MemberName FROM temp_sp_helprolemember +WHERE DbRole = 'db_securityadmin' ORDER BY MemberName; +GO + +-- tsql +DROP TABLE temp_sp_helprolemember; +GO + +-- CASE 8 +USE babel_5135_db1; +GO + +SELECT name, type, type_desc, default_schema_name, is_fixed_role, authentication_type_desc FROM sys.database_principals WHERE NAME = 'db_securityadmin'; +GO + +USE master; +GO + +-- CASE 9 - Restrictions +-- tsql +-- normal tsql login +CREATE LOGIN db_securityadmin_restrictions_login WITH password = '12345678'; +GO + +ALTER SERVER ROLE sysadmin ADD MEMBER db_securityadmin_restrictions_login; +GO + +-- psql +-- normal PG user +CREATE USER db_securityadmin_restrictions_pg_user WITH LOGIN CREATEROLE CREATEDB PASSWORD '12345678' inherit; +go + +-- tsql user=db_securityadmin_restrictions_login password=12345678 +-- a tsql login should not be able to rename/drop db_securityadmin and grant/revoke on it explicitly from tsql port +ALTER ROLE db_securityadmin WITH NAME = db_securityadmin1; +GO + +DROP ROLE db_securityadmin; +GO + +GRANT SELECT ON babel_5135_schema1.babel_5135_t1 TO db_securityadmin; +GO + +GRANT SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 TO db_securityadmin; +GO + +REVOKE SELECT ON babel_5135_schema1.babel_5135_t1 FROM db_securityadmin; +GO + +REVOKE SELECT, INSERT, UPDATE, DELETE, EXECUTE ON SCHEMA::babel_5135_schema1 FROM db_securityadmin; +GO + +-- psql user=db_securityadmin_restrictions_login password=12345678 +-- a tsql login should not be able to alter/grant/drop db_securityadmin from pg port +ALTER ROLE master_db_securityadmin NOCREATEROLE; +GO + +ALTER ROLE master_db_securityadmin WITH PASSWORD '12345678'; +GO + +ALTER ROLE master_db_securityadmin VALID UNTIL 'infinity'; +GO + +ALTER ROLE master_db_securityadmin WITH CONNECTION LIMIT 1; +GO + +-- GRANT master_db_securityadmin TO db_securityadmin_restrictions_login; +-- GO + +GRANT db_securityadmin_restrictions_login TO master_db_securityadmin; +GO + +-- REVOKE master_db_securityadmin FROM master_dbo; +-- GO + +REVOKE master_dbo FROM master_db_securityadmin; +GO + +DROP ROLE master_db_securityadmin; +GO + +SET SESSION AUTHORIZATION master_db_securityadmin; +GO + +SET ROLE master_db_securityadmin; +GO + +-- psql user=db_securityadmin_restrictions_pg_user password=12345678 +-- a normal psql user should not be able to alter/grant/drop db_securityadmin from pg port +ALTER ROLE master_db_securityadmin NOCREATEROLE; +GO + +ALTER ROLE master_db_securityadmin WITH PASSWORD '12345678'; +GO + +ALTER ROLE master_db_securityadmin VALID UNTIL 'infinity'; +GO + +ALTER ROLE master_db_securityadmin WITH CONNECTION LIMIT 1; +GO + +GRANT master_db_securityadmin TO db_securityadmin_restrictions_login; +GO + +GRANT db_securityadmin_restrictions_login TO master_db_securityadmin; +GO + +REVOKE master_db_securityadmin FROM master_dbo; +GO + +REVOKE master_dbo FROM master_db_securityadmin; +GO + +DROP ROLE master_db_securityadmin; +GO + +SET SESSION AUTHORIZATION master_db_securityadmin; +GO + +SET ROLE master_db_securityadmin; +GO + +-- psql +DROP USER db_securityadmin_restrictions_pg_user; +GO + +-- Need to terminate active session before cleaning up the login +SELECT pg_terminate_backend(pid) FROM pg_stat_get_activity(NULL) +WHERE sys.suser_name(usesysid) = 'db_securityadmin_restrictions_login' AND backend_type = 'client backend' AND usesysid IS NOT NULL; +GO + +-- tsql +DROP LOGIN db_securityadmin_restrictions_login; +GO diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index 797fb3d653a..f28f04ee92b 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -466,8 +466,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_11/schedule b/test/JDBC/upgrade/14_11/schedule index 0907a2c53fa..661397f16e3 100644 --- a/test/JDBC/upgrade/14_11/schedule +++ b/test/JDBC/upgrade/14_11/schedule @@ -464,8 +464,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_12/schedule b/test/JDBC/upgrade/14_12/schedule index e4615eb878f..df6135b063f 100644 --- a/test/JDBC/upgrade/14_12/schedule +++ b/test/JDBC/upgrade/14_12/schedule @@ -465,6 +465,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/14_13/schedule b/test/JDBC/upgrade/14_13/schedule index 080cc0b1dda..be7861dc301 100644 --- a/test/JDBC/upgrade/14_13/schedule +++ b/test/JDBC/upgrade/14_13/schedule @@ -465,8 +465,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_14/schedule b/test/JDBC/upgrade/14_14/schedule index 080cc0b1dda..be7861dc301 100644 --- a/test/JDBC/upgrade/14_14/schedule +++ b/test/JDBC/upgrade/14_14/schedule @@ -465,8 +465,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index 9eb61e037fc..a925aa65bf4 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -386,6 +386,7 @@ binary-datatype-operators BABEL-5059-before-14_7-or-15_2 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index 9af527dbc42..6b1c9fd83d5 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -397,8 +397,8 @@ binary-datatype-operators BABEL-5059-before-14_7-or-15_2 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index eca1396dfdf..06477d4b09b 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -434,8 +434,8 @@ binary-datatype-operators BABEL-5059-before-14_7-or-15_2 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index a68fcd8d1ef..92777d78f15 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -456,8 +456,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index d2a58da0dae..2f57cd2e93e 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -458,8 +458,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index a20b9de76c0..579f6901adb 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -461,8 +461,8 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter BABEL-5186 - diff --git a/test/JDBC/upgrade/15_1/schedule b/test/JDBC/upgrade/15_1/schedule index 965c5875fe4..8dfacc7e506 100644 --- a/test/JDBC/upgrade/15_1/schedule +++ b/test/JDBC/upgrade/15_1/schedule @@ -434,6 +434,7 @@ binary-datatype-operators BABEL-5059-before-14_7-or-15_2 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 2e79502ddf9..290033a35fd 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -469,6 +469,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index a9f19f4f338..9b0eb65601d 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -488,6 +488,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index e76cea69497..1cb710a9dd2 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -501,6 +501,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 datareader_datawriter diff --git a/test/JDBC/upgrade/15_5/schedule b/test/JDBC/upgrade/15_5/schedule index 16355c8887b..0cbc0bb7c68 100644 --- a/test/JDBC/upgrade/15_5/schedule +++ b/test/JDBC/upgrade/15_5/schedule @@ -532,6 +532,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 dbcreator_role diff --git a/test/JDBC/upgrade/15_6/schedule b/test/JDBC/upgrade/15_6/schedule index 2a5a258a333..1861706723b 100644 --- a/test/JDBC/upgrade/15_6/schedule +++ b/test/JDBC/upgrade/15_6/schedule @@ -548,6 +548,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 dbcreator_role diff --git a/test/JDBC/upgrade/15_7/schedule b/test/JDBC/upgrade/15_7/schedule index afd49a7e876..04bbbae8007 100644 --- a/test/JDBC/upgrade/15_7/schedule +++ b/test/JDBC/upgrade/15_7/schedule @@ -555,6 +555,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 GRANT_SCHEMA-before-15_9-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 diff --git a/test/JDBC/upgrade/15_8/schedule b/test/JDBC/upgrade/15_8/schedule index cb65169e099..ee1e08d4a85 100644 --- a/test/JDBC/upgrade/15_8/schedule +++ b/test/JDBC/upgrade/15_8/schedule @@ -546,6 +546,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 GRANT_SCHEMA-before-15_9-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 diff --git a/test/JDBC/upgrade/15_9/schedule b/test/JDBC/upgrade/15_9/schedule index 2eb61e62e88..3c7aae346e5 100644 --- a/test/JDBC/upgrade/15_9/schedule +++ b/test/JDBC/upgrade/15_9/schedule @@ -550,6 +550,7 @@ xml_exist-before-16_5 BABEL-5119_before_16_5 dbcreator_role db_accessadmin +db_securityadmin BABEL-CASE_EXPR datareader_datawriter BABEL-5186 diff --git a/test/JDBC/upgrade/16_1/schedule b/test/JDBC/upgrade/16_1/schedule index f8d7a8b205e..a88d6348186 100644 --- a/test/JDBC/upgrade/16_1/schedule +++ b/test/JDBC/upgrade/16_1/schedule @@ -541,6 +541,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin securityadmin_role dbcreator_role xml_exist-before-16_5 diff --git a/test/JDBC/upgrade/16_2/schedule b/test/JDBC/upgrade/16_2/schedule index 182b93b730e..800d693804e 100644 --- a/test/JDBC/upgrade/16_2/schedule +++ b/test/JDBC/upgrade/16_2/schedule @@ -557,6 +557,7 @@ BABEL-5059_before_16_5 cast-varchar-to-time dbcreator_role db_accessadmin +db_securityadmin xml_exist-before-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 BABEL-5186 diff --git a/test/JDBC/upgrade/16_3/schedule b/test/JDBC/upgrade/16_3/schedule index cad9c66ecba..4f7cfcd984f 100644 --- a/test/JDBC/upgrade/16_3/schedule +++ b/test/JDBC/upgrade/16_3/schedule @@ -559,6 +559,7 @@ binary-datatype-operators BABEL-5059_before_16_5 cast-varchar-to-time db_accessadmin +db_securityadmin xml_exist-before-16_5 GRANT_SCHEMA-before-15_9-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 diff --git a/test/JDBC/upgrade/16_4/schedule b/test/JDBC/upgrade/16_4/schedule index 2ff649328e7..a2bdf659411 100644 --- a/test/JDBC/upgrade/16_4/schedule +++ b/test/JDBC/upgrade/16_4/schedule @@ -572,6 +572,7 @@ cast-varchar-to-time xml_exist-before-16_5 BABEL-5119_before_16_5 db_accessadmin +db_securityadmin GRANT_SCHEMA-before-15_9-16_5 BABEL-CASE_EXPR-before-16_5-or-15_9 charindex_replace_patindex diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index ce4e776c7fb..e6dccea2c32 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -582,9 +582,9 @@ BABEL-5119 dbcreator_role BABEL-5129 db_accessadmin +db_securityadmin BABEL-CASE_EXPR charindex_replace_patindex BABEL-5186 BABEL-2736 datareader_datawriter - diff --git a/test/python/expected/sql_validation_framework/expected_drop.out b/test/python/expected/sql_validation_framework/expected_drop.out index c1e165f8a3c..5c0750c24e5 100644 --- a/test/python/expected/sql_validation_framework/expected_drop.out +++ b/test/python/expected/sql_validation_framework/expected_drop.out @@ -10,6 +10,12 @@ Unexpected drop found for cast in file babelfishpg_common--1.0.0--1.1.0.sql Unexpected drop found for cast in file babelfishpg_common--3.1.0--3.2.0.sql Unexpected drop found for function get_bbf_binary_ops_count in file babelfishpg_common--2.3.0--2.4.0.sql Unexpected drop found for function get_bbf_binary_ops_count in file babelfishpg_common--3.0.0--3.1.0.sql +Unexpected drop found for function sys.babelfishpg_common_get_babel_server_collation_oid in file babelfishpg_common--2.2.0--2.3.0.sql +Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.2.0--2.3.0.sql +Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.3.0--3.0.0.sql +Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.4.0--3.0.0.sql +Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.5.0--3.0.0.sql +Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.6.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_common--2.0.0--2.1.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_common--2.3.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_common--2.4.0--3.0.0.sql @@ -17,6 +23,9 @@ Unexpected drop found for function sys.babelfish_update_server_collation_name in Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_common--2.6.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_common--2.7.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.0.0--2.1.0.sql +Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.10.0--3.0.0.sql +Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.11.0--3.0.0.sql +Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.12.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.3.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.4.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.5.0--3.0.0.sql @@ -24,28 +33,18 @@ Unexpected drop found for function sys.babelfish_update_server_collation_name in Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.7.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.8.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.9.0--3.0.0.sql -Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.10.0--3.0.0.sql -Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.11.0--3.0.0.sql -Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--2.12.0--3.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.4.0--4.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.5.0--4.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.6.0--4.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.7.0--4.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.8.0--4.0.0.sql Unexpected drop found for function sys.babelfish_update_server_collation_name in file babelfishpg_tsql--3.9.0--4.0.0.sql -Unexpected drop found for function sys.babelfishpg_common_get_babel_server_collation_oid in file babelfishpg_common--2.2.0--2.3.0.sql -Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.2.0--2.3.0.sql -Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.3.0--3.0.0.sql -Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.4.0--3.0.0.sql -Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.5.0--3.0.0.sql -Unexpected drop found for function sys.babelfishpg_tsql_get_babel_server_collation_oid in file babelfishpg_tsql--2.6.0--3.0.0.sql Unexpected drop found for function sys.pg_extension_config_remove in file babelfishpg_tsql--3.1.0--3.2.0.sql -Unexpected drop found for operator sys.+ in file babelfishpg_common--1.1.0--1.2.0.sql Unexpected drop found for operator sys./ in file babelfishpg_common--1.1.0--1.2.0.sql Unexpected drop found for operator sys./ in file babelfishpg_common--1.1.0--1.2.0.sql Unexpected drop found for operator sys./ in file babelfishpg_common--1.1.0--1.2.0.sql +Unexpected drop found for operator sys.+ in file babelfishpg_common--1.1.0--1.2.0.sql Unexpected drop found for procedure babelfish_drop_deprecated_opclass in file babelfishpg_common--1.0.0--1.1.0.sql -Unexpected drop found for procedure sys.create_db_roles_during_upgrade in file babelfishpg_tsql--4.3.0--4.4.0.sql Unexpected drop found for procedure sys.babel_create_guest_schemas in file babelfishpg_tsql--2.3.0--2.4.0.sql Unexpected drop found for procedure sys.babel_create_guest_schemas in file babelfishpg_tsql--3.0.0--3.1.0.sql Unexpected drop found for procedure sys.babelfish_alter_default_privilege_on_schema in file babelfishpg_tsql--4.3.0--4.4.0.sql @@ -83,6 +82,7 @@ Unexpected drop found for procedure sys.babelfish_update_collation_to_default in Unexpected drop found for procedure sys.babelfish_update_collation_to_default in file babelfishpg_tsql--2.6.0--3.0.0.sql Unexpected drop found for procedure sys.babelfish_update_user_catalog_for_guest in file babelfishpg_tsql--2.2.0--2.3.0.sql Unexpected drop found for procedure sys.babelfish_update_user_catalog_for_guest_schema in file babelfishpg_tsql--3.3.0--3.4.0.sql +Unexpected drop found for procedure sys.create_db_roles_during_upgrade in file babelfishpg_tsql--4.4.0--4.5.0.sql Unexpected drop found for procedure sys.create_xp_qv_in_master_dbo in file babelfishpg_tsql--1.1.0--1.2.0.sql Unexpected drop found for procedure sys.sp_babelfish_grant_usage_to_all in file babelfishpg_tsql--1.1.0--1.2.0.sql Unexpected drop found for table "#temp_schedules_to_delete" in file babelfishpg_tsql--4.2.0--4.3.0.sql diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index d45b122b01d..9deafc30f46 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -977,7 +977,6 @@ View sys.change_tracking_tables View sys.database_files View sys.database_filestream_options View sys.database_recovery_status -View sys.database_role_members View sys.dm_hadr_cluster View sys.dm_hadr_database_replica_states View sys.dm_os_host_info