October 26, 2010 at 9:47 am
Hi,
I have a user that I want to give SELECT permissios to only a couple of tables. The database contains many tables, sps and views. I do not want him to see any of these objects except the those two tables.
I used SSMS to acheive this result for table objects. I did it by using Properties dialog of each table. It is very time consuming task. The number of sps and views is much bigger than number of tables in the database. It is very hard to do it one object at a time.
Can someone provide me a sample script to deny a user permissons of all types (to hide them from his view in SSMS) for objects of type Stored Procedures and Views? The server is 2k5.
Any help is highly appreciated.
Thanks.
Khalique
October 26, 2010 at 10:06 am
you want to use a query to generate the commands for you, based ont he metadata.
i just tested this: create user/login [Noobie];
ran the results of the script below.
logged in as that user, and with Object Explorer, could not see views or procs/functions, but could still see the tables.
/*--results
name (No column name)
VW_BUDGETS_APPLICATION DENY VIEW DEFINITION ON [VW_BUDGETS_APPLICATION] TO SomeRole
VW_FGSFUNITAFT4 DENY VIEW DEFINITION ON [VW_FGSFUNITAFT4] TO SomeRole
VW_BUDGETS_AWARD DENY VIEW DEFINITION ON [VW_BUDGETS_AWARD] TO SomeRole
*/
select name,'DENY VIEW DEFINITION ON ' + QUOTENAME(name) + ' TO SomeRole '
from sys.objects
where type_desc IN('VIEW',
'SQL_STORED_PROCEDURE',
'AGGREGATE_FUNCTION',
'SQL_INLINE_TABLE_VALUED_FUNCTION',
'SQL_TABLE_VALUED_FUNCTION',
'SQL_SCALAR_FUNCTION')
Lowell
October 26, 2010 at 3:01 pm
Thanks. Worked perfect!.
April 15, 2014 at 4:58 am
Thank you very much for the code.
The tables are not visible but, I can still see the data by select query.
How can I change in
I the following code possible
select name,'DENY SELECT DEFINITION ON ' + QUOTENAME(name) + ' TO VirtualOfficeReport '
from sys.objects
where type_desc IN('USER_TABLE',
'SQL_STORED_PROCEDURE',
'AGGREGATE_FUNCTION',
'SQL_INLINE_TABLE_VALUED_FUNCTION',
'SQL_TABLE_VALUED_FUNCTION',
'SQL_SCALAR_FUNCTION')
April 15, 2014 at 7:12 am
This seems backwards to me. When you build the user the first time, it should have no privs other than PUBLIC. Then grant individual privs. Better yet, make a DB role with the correct privs to the individual objects and then grant membership to that role.
You should also consider the idea of using Windows Authenticated Groups and Users.
--Jeff Moden
Change is inevitable... Change for the better is not.
June 8, 2016 at 3:49 pm
NOT WORKING.
User can still see ALL
Steve Nguyen
June 8, 2016 at 8:33 pm
stn11 (6/8/2016)
NOT WORKING.User can still see ALL
i would guess your user is a sysadmin, by mistake or due to mutliple roles.
easy to check:
select IS_SRVROLEMEMBER('sysadmin','mydomain\lowell')
Lowell
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply