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

Index cannot be created on view because the underlying object has a different owner Expand / Collapse
Author
Message
Posted Monday, September 9, 2013 5:34 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, June 19, 2014 2:34 AM
Points: 4, Visits: 155
Hello Guys,

We are getting the below error while creating the clustered index on the index view:

"Index cannot be created on view because the underlying object has a different owner"

The schemas of the "base table" referred in the view and actual schema of the "view" are owned by different database roles and that's why we are getting this error.

As a work-around, I am thinking of making "dbo" user as the owner of both the schemas (base table and indexed view schema) and then grant full permission to database roles of "base table" and "indexed view" on their respective schemas

Question: Does this approach has any security concerns when all the schemas will be owned by dbo user ?

Thanks in advance,

Vikas

Post #1492955
Posted Tuesday, September 10, 2013 5:05 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 6, 2014 1:35 AM
Points: 178, Visits: 547
Set it up in development.
Make the changes.
Try your best to take advantage of the new rights.




For better, quicker answers on T-SQL questions, read Jeff Moden's suggestions.

"Million-to-one chances crop up nine times out of ten." ― Terry Pratchett, Mort
Post #1493101
Posted Tuesday, September 10, 2013 6:42 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 6, 2014 1:35 AM
Points: 178, Visits: 547
Here's a script to reproduce the error and correct it.

CREATE SCHEMA Test1 AUTHORIZATION Guest
GO
CREATE SCHEMA Test2 AUTHORIZATION dbo
GO

IF OBJECT_ID('Test1.Tmp1') IS NOT NULL
DROP TABLE Test1.Tmp1

CREATE TABLE Test1.Tmp1
(
ID INT IDENTITY,
CharVal Char(1),
)

IF OBJECT_ID('Test1.Tmp2') IS NOT NULL
DROP TABLE Test2.Tmp2

CREATE TABLE Test2.Tmp2
(
ID2 INT IDENTITY,
CharVal2 Char(1)
)

INSERT Test1.Tmp1
SELECT TOP 100 CHAR(ABS(CHECKSUM(NEWID()) % 26) +97)
FROM sys.all_columns c1, sys.all_columns c2

INSERT Test2.Tmp2
SELECT TOP 100 CHAR(ABS(CHECKSUM(NEWID()) % 26) +97)
FROM sys.all_columns c1, sys.all_columns c2
GO
-- DROP VIEW Test1.View1
CREATE VIEW Test1.View1
WITH SCHEMABINDING
AS
(
SELECT T1.ID, T1.CharVal, T2.CharVal2
FROM Test1.Tmp1 T1
JOIN Test2.Tmp2 T2
ON T1.ID = T2.ID2
)
GO

CREATE UNIQUE CLUSTERED INDEX UCI_TmpTest ON Test1.View1 (ID, CharVal, CharVal2)
--Generates error
--Msg 1938, Level 16, State 1, Line 1
--Index cannot be created on view 'View1' because the underlying object 'Tmp2' has a different owner.
GO
ALTER AUTHORIZATION ON SCHEMA::Test1 TO dbo
GO
-- Try creating the unique clustered index again
CREATE UNIQUE CLUSTERED INDEX UCI_TmpTest ON Test1.View1 (ID, CharVal, CharVal2)
GO

DROP VIEW Test1.View1
DROP TABLE Test1.Tmp1
DROP TABLE Test2.Tmp2

DROP SCHEMA Test1
DROP SCHEMA Test2

Make sure you make a reversing script just in case.




For better, quicker answers on T-SQL questions, read Jeff Moden's suggestions.

"Million-to-one chances crop up nine times out of ten." ― Terry Pratchett, Mort
Post #1493141
Posted Tuesday, September 10, 2013 4:14 PM


Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Wednesday, July 23, 2014 2:28 PM
Points: 786, Visits: 691
It is difficult to answer the question, because I don't know why you set up different schema owners in the first place. My preference is to have dbo to own everything, but that also requires the right way of thinking about security for that model.



Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Post #1493388
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse