February 14, 2014 at 1:51 pm
Can someone please give me example SQL code to do the following:
* Create Scheme xyz
* Add views to schema xyz
* create user that only can see view in xyz
* make sure user can't see any tables in the database
-- Note: All tables created as dbo
Thank you!
February 14, 2014 at 2:03 pm
Have you even tried looking for "CREATE SCHEMA" on google?
February 14, 2014 at 2:10 pm
Luis Cazares (2/14/2014)
Have you even tried looking for "CREATE SCHEMA" on google?
Yes. I tried it - made the user - made the schema - logged in as the user - couldn't select the "customer" table but could find out it was there - couldn't see the view.
So yes... I tried and I then came here seeking help.
Mike
P.S. Why waste the keystokes asking me if I looked - if you don't want to help - no problem - but do you have to give grief? Maybe, I am super swamped and just need some help.
February 14, 2014 at 2:18 pm
take a look at this post i made a few years ago, it's got a nice example of a couple of schemas you can fiddle with.
http://www.sqlservercentral.com/Forums/Topic1216364-1550-1.aspx#bm1216431
Lowell
February 14, 2014 at 2:23 pm
I'm sorry, your answer makes it completely different. I'm sorry but many people come here and ask questions without even trying anything (some people believe that is easier to write a post here than to press F5 on SSMS).
To grant or remove permissions, you need to be sure you're not the user receivng the permissions.
You have a group of statements to manage permissions: GRANT, DENY, REVOKE.
You can GRANT permissions on the views (or the new schema) to allow the user to work with it. And you can DENY permissions on the dbo schema.
Can you post exactly what you've tried? Have you done it with T-SQL or with the graphic interface?
February 14, 2014 at 2:24 pm
Wow. Thank you! This will really help.
Mike
February 14, 2014 at 2:28 pm
Luis Cazares (2/14/2014)
I'm sorry, your answer makes it completely different. I'm sorry but many people come here and ask questions without even trying anything (some people believe that is easier to write a post here than to press F5 on SSMS).To grant or remove permissions, you need to be sure you're not the user receivng the permissions.
You have a group of statements to manage permissions: GRANT, DENY, REVOKE.
You can GRANT permissions on the views (or the new schema) to allow the user to work with it. And you can DENY permissions on the dbo schema.
Can you post exactly what you've tried? Have you done it with T-SQL or with the graphic interface?
I understand that some post without trying. That is life. Does it really matter if they tried? If they understand the solution you present or they learn something, isn't it what the forum is really about? Yes, some may take advantage of it. But some, like me, may read what others have asked and try to figure it out.
Unfortunately, I the testing I did, I did it completely in the interface.
Mike
February 14, 2014 at 2:32 pm
mike 57299 (2/14/2014)
Can someone please give me example SQL code to do the following:* Create Scheme xyz
* Add views to schema xyz
the above are not necessary to make other objects not-visible/accessible.
you can do all that with a simple user, without the deep complexity of alternate schemas
* create user that only can see view in xyz
* make sure user can't see any tables in the database
-- Note: All tables created as dbo
Thank you!
-- a table to prove our user cannot see it
create table dbo.noTableForYou(id int,otherData varchar(30) )
--some sample data
insert into dbo.noTableForYou
select top 5 object_id,name from sys.objects
GO
--a view of the data
create view dbo.xyz
AS
SELECT * FROM dbo.noTableForYou
GO
--our test user
CREATE USER TestUser WITHOUT LOGIN
--grant the only object he can see
GRANT SELECT ON dbo.xyz TO TestUser
--no test as our user
EXECUTE AS user='TestUser'
--can i see the data?
SELECT * FROM dbo.xyz
--can i see any objects ?
select * from sys.objects
--can i directly access the underlying table, if i know it exists?
SELECT * FROM dbo.noTableForYou
--change back into sysadmin
REVERT;
--cleanup my mess
DROP USER TestUser
DROP VIEW dbo.xyz
DROP TABLE dbo.noTableForYou
Lowell
February 14, 2014 at 2:34 pm
mike 57299 (2/14/2014)
Does it really matter if they tried? If they understand the solution you present or they learn something, isn't it what the forum is really about?
It matters to me. I'm willing to give many solutions, but if people never try, they will never learn. I want people to learn how to learn and find solutions on their own.
Unfortunately, I the testing I did, I did it completely in the interface.
Mike
As a suggestion, now that you're learning. If you find it easier to work with the GUI, use the option to generate scripts instead of clicking OK. It will help you understand what you're doing and you can learn more.
March 25, 2014 at 9:01 am
Followup:
Here is a picture of what I see if I access the SQL data via Access/ODBC. How do I get rid of the Information_Schema & Sys lines?
(Picture attached.)
Mike
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply