优乐官网 当前位置:首页>优乐官网>正文

优乐官网

发布时间:2019-03-19

原标题:SQL Server元数据损坏(metadata corruption)修复

SQL Server元数据损坏(metadata corruption)修复


 

在升级一个SQL Server 2000的数据库时,遇到了一致性错误,其中有几个错误是元数据损坏(metadata corruption),特意研究了一下这个案例,因为以前也零零散散的遇到过一些一致性相关错误,但是难得遇到元数据损坏的案例。

 

如下所示,数据库从SQL Server 2000还原到SQL Server 2008以后,在做一致性检查时,发现有元数据损坏(metadata corruption),下面是实验是构造的一个测试环境

 

DBCC CHECKCATALOG (TEST) WITH NO_INFOMSGS;
GO
 
DBCC CHECKDB(TEST) WITH NO_INFOMSGS;
GO

 

 

Msg 8992, Level 16, State 1, Line 1

Check Catalog Msg 3853, State 1: Attribute (object_id=1362819917) of row (object_id=1362819917,parameter_id=1) in sys.parameters does not have a matching row (object_id=1362819917) in sys.objects.

Msg 8992, Level 16, State 1, Line 1

Check Catalog Msg 3853, State 1: Attribute (object_id=1362819917) of row (object_id=1362819917,parameter_id=2) in sys.parameters does not have a matching row (object_id=1362819917) in sys.objects.

CHECKDB found 0 allocation errors and 2 consistency errors not associated with any single object.

CHECKDB found 0 allocation errors and 2 consistency errors in database "TEST".

 

 

 

clip_image001

 

 

 

 

那么我们先找到系统视图sys.parameters的数据来源于那个系统基础表(System Base-Table Metadata),如下脚本所示,我们可以找到sys.parameters 最终来源于sys.syscolpars和 sys.sysobjvalues(关于如何获取系统视图定义,此处不做展开分析)

 

SET QUOTED_IDENTIFIER ON
SET ANSI_NULLS ON
GO
CREATE VIEW sys.parameters AS
    SELECT object_id, name,
        parameter_id, system_type_id,
        user_type_id, max_length,
        precision, scale,
        is_output, is_cursor_ref,
        has_default_value, is_xml_document,
        default_value, xml_collection_id,
        is_readonly
    FROM sys.parameters$
    WHERE number = 1
 
GO
 
 
 
CREATE VIEW sys.parameters$ AS
    SELECT c.id AS object_id,
        c.number, c.name,
        c.colid AS parameter_id,
        c.xtype AS system_type_id,
        c.utype AS user_type_id,
        c.length AS max_length,
        c.prec AS precision,
        c.scale AS scale,
        sysconv(bit, c.status & 512) AS is_output,        -- CPM_OUTPUT
        sysconv(bit, c.status & 1024) AS is_cursor_ref,    -- CPM_CURSORREF
        sysconv(bit, isnull(v.objid, 0)) AS has_default_value,
        sysconv(bit, c.status & 2048) AS is_xml_document, -- CPM_XML_DOC        
        v.value AS default_value,
        xmlns AS xml_collection_id,
        sysconv(bit, c.status & 4194304) AS is_readonly -- CPM_IS_READONLY = 0x00400000
    FROM sys.syscolpars c
    LEFT JOIN sys.sysobjvalues v ON v.valclass = 9 AND v.objid = c.id AND v.subobjid = c.colid AND v.valnum = 0    -- SVC_PARAMDEFAULT
    WHERE number > 0 AND has_access("CO", c.id) = 1

 

 

但是系统基础表sys.syscolpars和sys.sysobjvalues在正常情况下是不可见的。只有在数据库专用管理员连接方式(DAC Dedicated Administrator Connection)连接下才能可见。如下所示,可以判断数据来源于sys.syscolpars系统基础表。

 

 

clip_image002

 

 

此时即使在专用管理员连接下面也是无法删除这些数据的,会报Ad hoc update to system catalogs is not supported,对应中文提示为不支持对系统目录进行即席更新。如下所示:

 

 

EXEC sp_configure "allow_updates", 1;

RECONFIGURE WITH OVERRIDE;

GO

USE TEST;

GO

DELETE FROM  sys.syscolpars WHERE id=1362819917;

GO

 

 

clip_image003

 

 

 

那么难道就没有办法解决这种问题了吗? 答案是当然有,不过,这种方式是没有官方文档而且也不被官方Support的,如果你要按下面方法操作,是有一定风险的。所以如果你决定按照下面方式修复元数据损坏的话,先做好备份。以防万一

 

你必须将数据库实例在单用户模式下面启动,然后以专用管理员(DAC)连接到数据库,然后就可以删除基础表下面的数据了,如下截图所示:

 

 

C:Documents and Settings>net stop mssqlserver

The SQL Server (MSSQLSERVER) service is stopping.

The SQL Server (MSSQLSERVER) service was stopped successfully.

 

 

C:Documents and Settings>net start mssqlserver /m"Microsoft SQL Serve

r Management Studio - Query"

The SQL Server (MSSQLSERVER) service is starting.

The SQL Server (MSSQLSERVER) service was started successfully.

 

 

USE TEST;
GO
DELETE FROM  sys.syscolpars WHERE id=1362819917;
GO
 
----------------------------------------------------------------------------------
Warning: System table ID 41 has been updated directly in database ID 5 and cache coherence may not have been maintained. SQL Server should be restarted.
 

当前文章://5zp5m.html

发布时间:2019-03-19 03:56:11

云顶娱乐网站|首页 永盛娱乐棋牌可靠吗 必发365网站打不开 亚虎999娱乐官网激活 u乐平台注册 

责任编辑:卓开陵

随机推荐