前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >SQL Server执行sp_changeobjectowner遇到"Msg 15001, Level 16,..."错误探究

SQL Server执行sp_changeobjectowner遇到"Msg 15001, Level 16,..."错误探究

原创
作者头像
潇湘隐者
修改2021-02-25 18:10:54
4940
修改2021-02-25 18:10:54
举报
文章被收录于专栏:潇湘隐者潇湘隐者

在SQL Server中使用sp_changeobjectowner存储过程修改对象所有者(Owner)时,可能会遇到下面错误信息,当然对象klb.[k3]这个表确实是存在的。如下所示:

注意:个人测试环境为SQL Server 2014的标准版,如有不同情况,请以实际环境为准。

代码语言:javascript
复制
USE AdventureWorks2014;
GO
EXEC sp_changeobjectowner 'klb.k3', 'dbo';
GO

Msg 15001, Level 16, State 1, Procedure sp_changeobjectowner, Line 81
Object 'klb.[V_Test]' does not exist or is not a valid object for this operation.

当然你再次执行的话,可能会遇到同样的错误提示,但是Line的值有所变化,变成了99. (这里是因为在脚本第二处抛出错误)

Msg 15001, Level 16, State 1, Procedure sp_changeobjectowner, Line 99 Object 'klb.[k3]' does not exist or is not a valid object for this operation.

我们获取sp_changeobjectowner存储过程的定义如下:

代码语言:javascript
复制
SET QUOTED_IDENTIFIER ON
SET ANSI_NULLS ON
GO
create procedure sys.sp_changeobjectowner
 @objname nvarchar(776),  -- may be "[owner].[object]"
 @newowner sysname    -- must be entry from sysusers
as
 Set nocount      on
 Set ansi_padding on
 declare @objid  int,
         @newuid  int,
         @ret  int,
         @oldowner sysname,
         @stmtS  nvarchar(4000)

 -- CHECK PERMISSIONS: Because changing owner changes both schema and
 -- permissions, the caller must be one of:
 -- (1) db_owner
 -- (2) db_ddladmin AND db_securityadmin
    if (is_member('db_owner') = 0) and
  (is_member('db_securityadmin') = 0 OR is_member('db_ddladmin') = 0)
    begin
  EXEC %%System().AuditEvent(ID = 1094864724, Success = 0, TargetLoginName = NULL, TargetUserName = @newowner, Role = NULL, Object = @objname, Provider = NULL, Server = NULL)
  raiserror(15247,-1,-1)
  return (1)
    end
    else
    begin
  EXEC %%System().AuditEvent(ID = 1094864724, Success = 1, TargetLoginName = NULL, TargetUserName = @newowner, Role = NULL, Object = @objname, Provider = NULL, Server = NULL)
    end

 if parsename(@objname, 1) is null
 begin
  raiserror(15253, -1, -1, @objname)
  return (1)
 end

 BEGIN TRANSACTION

 -- RESOLVE OBJECT NAME (CANNOT BE A CHILD OBJECT: TRIGGER/CONSTRAINT) --
 select @objid = object_id(@objname, 'local')
 if not (@objid is null)
 begin
  EXEC %%Object(MultiName = @objname).LockMatchID(ID = @objid, Exclusive = 1, BindInternal = 0)
  if (@@error <> 0) -- lock failed
   select @objid = null
 end
 if (@objid is null) OR
  (select parent_obj from sysobjects where id = @objid) <> 0 OR
  ObjectProperty(@objid, 'IsSystemTable') = 1 OR
  parsename(@objname, 3) is not null OR
  parsename(@objname, 4) is not null OR
  exists (select * from sys.objects where object_id = @objid and schema_id in (3,4))  OR -- INFORMATION_SCHEMA, sys
  -- Check for Dependencies: No RENAME or CHANGEOWNER of OBJECT when exists:
  EXISTS (SELECT * FROM sysdepends d WHERE
   d.depid = @objid  -- A dependency on this object
   AND d.deptype > 0  -- that is enforced
   AND @objid <> d.id  -- that isn't a self-reference (self-references don't use object name)
   AND @objid <>   -- And isn't a reference from a child object (also don't use object name)
    (SELECT o.parent_obj FROM sysobjects o WHERE o.id = d.id)
   )
 begin
  -- OBJECT NOT FOUND
  COMMIT TRANSACTION
  raiserror(15001,-1,-1,@objname)
  return 1
 end

 -- object's schema name must be the same as the schema owner's name
 if not exists (select so.name 
  from sys.objects so
  join sys.schemas ss on so.schema_id = ss.schema_id 
  join sys.database_principals su on ss.principal_id = su.principal_id
  where object_id = @objid and so.principal_id is null and ss.name = su.name)
 begin
  -- OBJECT NOT FOUND
  COMMIT TRANSACTION
  raiserror(15001,-1,-1,@objname)
  return 1
 end
 
 select @oldowner = ssch.name from sys.schemas ssch join sys.objects so on (so.schema_id = ssch.schema_id) where object_id = @objid
 -- SHARE LOCK OLD SCHEMA, PREVENT DROP OF THE OWNER WHILE TXN ACTIVE --
  -- (rollback could cause phantom owner) --
 EXEC %%ObjectSchema (Name = @oldowner).Lock(Exclusive = 0) -- should succeed due to object lock above

 -- SHARE LOCK NEW SCHEMA --
 EXEC %%ObjectSchema (Name = @newowner).Lock(Exclusive = 0) -- may fail, check below anyway

 -- RESOLVE NEW OWNER NAME (ATTEMPT ADDING IMPLICIT ROW FOR NT NAME) --
    --  Disallow aliases, and public cannot own objects --
 if @@error = 0 -- lock success, indicate new owner may exist, verify further
  select @newuid = schema_id from sys.schemas where name = @newowner
       and schema_id not in (3,4) -- INFORMATION_SCHEMA, sys
 
    if @newuid is null -- indicate lock failed
    begin
  EXEC @ret = sys.sp_MSadduser_implicit_ntlogin @newowner
  if (@ret = 0) -- success
   select @newuid = schema_id from sys.schemas where name = @newowner
   -- Member locked by sp_MSadduser_implicit_ntlogin
    end

    if @newuid is null OR
  -- the schema name and its owner name must be the same
  not exists (select ss.name
   from sys.schemas ss
   join sys.database_principals su on ss.principal_id = su.principal_id
   where ss.name = @newowner and ss.name = su.name)
    begin
  -- Implicit login added above is not rolled back
  -- This is same as SQL 2000
  COMMIT TRANSACTION
  raiserror(15411, -1, -1, @newowner)
  return (1)
    end

 select @stmtS = 'ALTER SCHEMA '
 select @stmtS = @stmtS + quotename(@newowner)
 select @stmtS = @stmtS + ' TRANSFER '
 if parsename(@objname, 2) is not null
  select @stmtS = @stmtS + quotename(parsename(@objname, 2)) + '.'
 select @stmtS = @stmtS + quotename(parsename(@objname, 1))

 exec (@stmtS)
 IF @@ERROR <> 0
 BEGIN
  -- Nested transaction is used by alter schema statement
  COMMIT TRANSACTION
  return (1)
 END

 COMMIT TRANSACTION
 -- WARNING AFTER THE OWNER TRANSFER --
 raiserror(15477,-1,-1)
 return (0) -- sp_changeobjectowner

GO

通过分析存储过程,我们发现在两个地方可能抛出Msg 15001的错误信息,如下所示

代码语言:javascript
复制
 if (@objid is null) OR
  (select parent_obj from sysobjects where id = @objid) <> 0 OR
  ObjectProperty(@objid, 'IsSystemTable') = 1 OR
  parsename(@objname, 3) is not null OR
  parsename(@objname, 4) is not null OR
  exists (select * from sys.objects where object_id = @objid and schema_id in (3,4))  OR -- INFORMATION_SCHEMA, sys
  -- Check for Dependencies: No RENAME or CHANGEOWNER of OBJECT when exists:
  EXISTS (SELECT * FROM sysdepends d WHERE
   d.depid = @objid  -- A dependency on this object
   AND d.deptype > 0  -- that is enforced
   AND @objid <> d.id  -- that isn't a self-reference (self-references don't use object name)
   AND @objid <>   -- And isn't a reference from a child object (also don't use object name)
    (SELECT o.parent_obj FROM sysobjects o WHERE o.id = d.id)
   )
 begin
  -- OBJECT NOT FOUND
  COMMIT TRANSACTION
  raiserror(15001,-1,-1,@objname)
  return 1
 end

12

代码语言:javascript
复制
 -- object's schema name must be the same as the schema owner's name
 if not exists (select so.name 
  from sys.objects so
  join sys.schemas ss on so.schema_id = ss.schema_id 
  join sys.database_principals su on ss.principal_id = su.principal_id
  where object_id = @objid and so.principal_id is null and ss.name = su.name)
 begin
  -- OBJECT NOT FOUND
  COMMIT TRANSACTION
  raiserror(15001,-1,-1,@objname)
  return 1
 end

然后我们分析发现在第二个SQL会因为不满足条件,抛出错误信息,具体分析截图所示

其实从脚本的注释信息“object's schema name must be the same as the schema owner's name”,我们已经知道,这个脚本有个逻辑,判断对象的schema name和schema owner's name是否一致,如果不一致的话,就抛出错误信息。而这里遇到这个问题是因为我们下面脚本恰恰修改了klb这个schema的schema owner,所以才导致了这个错误出现。

代码语言:javascript
复制
USE AdventureWorks2014;
GO
ALTER AUTHORIZATION ON SCHEMA::[klb]  TO [dbo];

这里将klb的schema owner修改回来,然后执行sp_changeobjectowner就会OK了。

代码语言:javascript
复制
USE AdventureWorks2014;
GO
ALTER AUTHORIZATION ON SCHEMA::[klb]  TO [klb];
GO
USE AdventureWorks2014;
GO
EXEC sp_changeobjectowner 'klb.[k3]', 'dbo';
GO

原创声明:本文系作者授权腾讯云开发者社区发表,未经许可,不得转载。

如有侵权,请联系 cloudcommunity@tencent.com 删除。

原创声明:本文系作者授权腾讯云开发者社区发表,未经许可,不得转载。

如有侵权,请联系 cloudcommunity@tencent.com 删除。

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
相关产品与服务
云数据库 SQL Server
腾讯云数据库 SQL Server (TencentDB for SQL Server)是业界最常用的商用数据库之一,对基于 Windows 架构的应用程序具有完美的支持。TencentDB for SQL Server 拥有微软正版授权,可持续为用户提供最新的功能,避免未授权使用软件的风险。具有即开即用、稳定可靠、安全运行、弹性扩缩等特点。
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档