database role wich only allows reading, except some specific table columns

Pablo gil 86 Reputation points
2021-08-30T00:32:38.627+00:00

I want to create some custom database roles, which only allow their members to SELECT all tables except some specific tables with some columns DENY
this is my attempt :

CREATE ROLE CustomDatabaseRole01
GO
DENY SELECT ON OBJECT::dbo.Table1(c1,c2) TO 
CustomDatabaseRole01
GO
DENY SELECT ON OBJECT::dbo.Table2(c3,c4) TO 
CustomDatabaseRole01
GO    
ALTER ROLE db_datareader ADD MEMBER UserTest01
GO
ALTER ROLE CustomDataBaseRole01 ADD MEMBER UserTest01
GO

this does not work, you can select any column in any table

Transact-SQL
Transact-SQL
A Microsoft extension to the ANSI SQL language that includes procedural programming, local variables, and various support functions.
4,707 questions
0 comments No comments
{count} votes

Accepted answer
  1. MelissaMa-MSFT 24,221 Reputation points
    2021-08-30T01:34:08.697+00:00

    Hi @Pablo gil ,

    Welcome to Microsoft Q&A!

    Please refer below example and check whether it is helpful to you.

     create table table1  
     (c1 int,  
     c2 int,  
     c3 int,  
     c4 int)  
      
     insert into table1 values  
     (1,2,3,4),  
     (5,6,7,8)  
      
      create table table2  
     (c1 int,  
     c2 int,  
     c3 int,  
     c4 int)  
      
     insert into table2 values  
     (11,12,13,14),  
     (15,16,17,18)  
    
    CREATE ROLE CustomDatabaseRole01  
    GO  
    CREATE USER CustomPerson WITHOUT LOGIN;  
    GO   
    EXEC sp_addrolemember @membername = 'CustomPerson', @rolename = 'CustomDatabaseRole01';  
    GO  
    GRANT SELECT ON dbo.Table1 TO CustomDatabaseRole01;  
    GO  
    GRANT SELECT ON dbo.Table2 TO CustomDatabaseRole01;  
    GO  
    DENY SELECT ON dbo.Table1(c1,c2) TO CustomDatabaseRole01;  
    GO  
    DENY SELECT ON dbo.Table2(c3,c4) TO CustomDatabaseRole01;  
    GO   
    

    We could validate it below with this role.

    EXECUTE AS USER = 'CustomPerson';  
    GO  
    SELECT * FROM dbo.Table1;  
    GO   
    REVERT;  
    GO  
    

    We get below error.

    Msg 230, Level 14, State 1, Line 45  
    The SELECT permission was denied on the column 'c1' of the object 'table1', database 'prdtest', schema 'dbo'.  
    Msg 230, Level 14, State 1, Line 45  
    The SELECT permission was denied on the column 'c2' of the object 'table1', database 'prdtest', schema 'dbo'.  
    

    We made another test below:

    EXECUTE AS USER = 'CustomPerson';  
    GO  
    SELECT C3,C4 FROM dbo.Table1;  
    GO   
    REVERT;  
    GO  
    

    Output:

    C3	C4  
    3	4  
    7	8  
    

    You could also refer this article for more details.

    Best regards,
    Melissa


    If the answer is helpful, please click "Accept Answer" and upvote it.
    Note: Please follow the steps in our documentation to enable e-mail notifications if you want to receive the related email notification for this thread.

    0 comments No comments

0 additional answers

Sort by: Most helpful

Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.