Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to hide objects (sp, views, tables) from a user? Expand / Collapse
Author
Message
Posted Tuesday, October 26, 2010 9:47 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, November 13, 2014 8:12 AM
Points: 50, Visits: 196
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
Post #1010937
Posted Tuesday, October 26, 2010 10:06 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:31 AM
Points: 12,962, Visits: 32,501
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1010957
Posted Tuesday, October 26, 2010 3:01 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, November 13, 2014 8:12 AM
Points: 50, Visits: 196
Thanks. Worked perfect!.
Post #1011165
Posted Tuesday, April 15, 2014 4:58 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, April 15, 2014 4:56 AM
Points: 1, Visits: 0
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')
Post #1561808
Posted Tuesday, April 15, 2014 7:12 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 2:11 PM
Points: 35,772, Visits: 32,441
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1561857
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse