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.