January 29, 2013 at 7:09 pm
At the risk of posting yet another message on cross chaining... I'm at my wits end. I've read and read until my eyes hurt. I'm missing something. All I want to do is create a view in database B that accesses an table in database A, that I don't want the user to ever access directly.
Here's the story: I have a giant database called "DataMart". In that database is a table innocuously called "Branch". According to the Auditors, the branch table contains data that will cause some people to go blind. Some of those people are my friends, and I would hate for that to happen (to the friends list).
I have a 2nd database called "MiniMart" where I plan to park views that a) reduces the number of objects they can see and b) restricts (or mangles) columns they cannot see.
Here is what I have:
SQL Server 2k8
Cross DB Chaining at the server is OFF.
Cross DB Chaining in both databases is ON
Trustworthy is ON for both databases.
Both databases are owned by the same user (idAdmin)
SELECT is revoked for PUBLIC on DataMart.DBO.Branch
my view and the Branch table are bothed owned by DBO.
I have a test user called "LowAccessTest", who exists as a user in DataMart but has no specific privileges (If I give this user db_datareader, they can see everything in the datamart database).
LowAccessTest is db_datareader in MiniMart.
In MiniMart, I have created a view:
create view DBO.limited_access_test as
select branch_nbr, name from datamart.dbo.branch
GO
grant select on limited_access_test to LowAccessTest
I then make a connection to MiniMart using LowAccessTest and attempt to query limited_access_test and I get:
Error: The SELECT permission was denied on the object 'BRANCH', database 'DataMart, schema 'dbo'. (State:42000, Native Code: E5)
If I make LowAccessTest a db_datareader in DataMart, my view works, but I can also query datamart.dbo.branch.
If I turn of db_datareader and grant Select on datamart.dbo.branch to LowAccessTest my view works, but I can also query datamart.dbo.branch.
What have I missed?
January 30, 2013 at 1:18 am
jchapman (1/29/2013)
...I have a test user called "LowAccessTest", who exists as a user in DataMart but has no specific privileges (If I give this user db_datareader, they can see everything in the datamart database).
Why you want add LowAccessTest to role db_reader in the DataMart? You should give him only select on the table
January 30, 2013 at 6:28 am
I don't. I only included that to illustrate that if I open up access the user can query the table. Ideally, I do not want to grant select rights on the underlying table at all .. Just the view.
January 30, 2013 at 7:27 am
You should not have to enable the TRUSTWORTHY bit. In fact I would recommend turning that off if only enabled during this effort in an attempt to get something working.
Steps that work:
- Enable cross-database ownership chaining on DataMart and MiniMart databases.
- Create Database User in DataMart and MiniMart from same Server Login.
- Create view in MiniMart that references table in DataMart.
- Grant SELECT on VIEW in MiniMart.
Here is a quick demo:
USE master
GO
CREATE LOGIN LowAccessTest WITH PASSWORD = 'mypwd!'
GO
--------------------------------------------------------------------------
CREATE DATABASE MyDataMart
GO
ALTER AUTHORIZATION ON DATABASE::MyDataMart TO sa
ALTER DATABASE MyDataMart SET DB_CHAINING ON;
GO
USE MyDataMart
GO
CREATE USER LowAccessTest FROM LOGIN LowAccessTest WITH DEFAULT_SCHEMA = dbo;
GO
CREATE TABLE dbo.Branch (id INT)
GO
--------------------------------------------------------------------------
CREATE DATABASE MyMiniMart
GO
ALTER AUTHORIZATION ON DATABASE::MyMiniMart TO sa
ALTER DATABASE MyMiniMart SET DB_CHAINING ON;
GO
USE MyMiniMart
GO
CREATE USER LowAccessTest FROM LOGIN LowAccessTest WITH DEFAULT_SCHEMA = dbo;
GO
CREATE VIEW dbo.limited_access_test
AS
SELECT id
FROM MyDataMart.dbo.branch
GO
GRANT SELECT ON dbo.limited_access_test TO LowAccessTest
GO
--------------------------------------------------------------------------
-- succeeds
USE MyMiniMart
GO
EXECUTE AS LOGIN = 'LowAccessTest'
GO
SELECT * FROM dbo.limited_access_test;
GO
REVERT
GO
--------------------------------------------------------------------------
-- fails with error, as it should
USE MyDataMart
GO
EXECUTE AS LOGIN = 'LowAccessTest'
GO
SELECT * FROM dbo.Branch;
GO
REVERT
GO
And the cleanup:
USE master
ALTER DATABASE MyDataMart SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
DROP DATABASE MyDataMart
ALTER DATABASE MyMiniMart SET SINGLE_USER WITH ROLLBACK IMMEDIATE;
DROP DATABASE MyMiniMart
DROP LOGIN LowAccessTest;
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
January 31, 2013 at 3:24 pm
Well I'm glad I wasn't completely crazy... I had the concept right... but obviously I missed a piece.
Thank you SO much for that code. I ran your example as is, and "poof" it worked, as advertised (not suprised, just pleased!).
I then modified the code to issue the alters to my existing databases... first pass, it didn't work. Second pass, I deleted the LowAccessTest user from both databases and started clean. "poof" it worked.
I think the key however, is (as you indicated in your checklist), is the database owners. If I issue a Alter Auth on one, and set the owner to SA, set the owner to idAdmin on the other, it's broken. Make them the same, and "poof".
I know I checked the owners... obviously I missed something, or just had so many plates spinning by that point, and stopped paying attention to the details.
I really appreciate the amount of time you spent on that script and the explaination. Thank you.
If you ever find your self in Northern New England, drop me a note; Dinner and and epic Belgium beers are on me.
January 31, 2013 at 3:34 pm
It was my pleasure. I am in Denver, CO and do not expect to be out that way in the near future but that's a heck of a nice offer, thanks for brightening my afternoon 😀
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply