SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to hide objects (sp, views, tables) from a user?


How to hide objects (sp, views, tables) from a user?

Author
Message
rehman-615909
rehman-615909
SSC Veteran
SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)

Group: General Forum Members
Points: 255 Visits: 209
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
Lowell
Lowell
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72364 Visits: 40942
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
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
rehman-615909
rehman-615909
SSC Veteran
SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)SSC Veteran (255 reputation)

Group: General Forum Members
Points: 255 Visits: 209
Thanks. Worked perfect!.
phardik
phardik
Grasshopper
Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)

Group: General Forum Members
Points: 19 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')
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)SSC Guru (216K reputation)

Group: General Forum Members
Points: 216384 Visits: 41986
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
stn11
stn11
Grasshopper
Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)

Group: General Forum Members
Points: 19 Visits: 229
NOT WORKING.

User can still see ALL


Steve Nguyen
Lowell
Lowell
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72364 Visits: 40942
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
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search