美文网首页
SqlServer表、日志查询

SqlServer表、日志查询

作者: 安安汐而 | 来源:发表于2018-09-07 16:05 被阅读0次

    数据库空间大小

    --日志空间占用
    dbcc sqlperf(logspace) with no_infomsgs
    
    --数据库表空间大小
    SELECT 
        t.NAME AS TableName,
        s.Name AS SchemaName,
        p.rows AS RowCounts,
        SUM(a.total_pages) * 8 AS TotalSpaceKB, 
        CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS TotalSpaceMB,
        SUM(a.used_pages) * 8 AS UsedSpaceKB, 
        CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS UsedSpaceMB, 
        (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB,
        CAST(ROUND(((SUM(a.total_pages) - SUM(a.used_pages)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSpaceMB
    FROM 
        sys.tables t
    INNER JOIN      
        sys.indexes i ON t.OBJECT_ID = i.object_id
    INNER JOIN 
        sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
    INNER JOIN 
        sys.allocation_units a ON p.partition_id = a.container_id
    LEFT OUTER JOIN 
        sys.schemas s ON t.schema_id = s.schema_id
    WHERE 
        t.NAME NOT LIKE 'dt%' 
        AND t.is_ms_shipped = 0
        AND i.OBJECT_ID > 255 
    GROUP BY 
        t.Name, s.Name, p.Rows
    ORDER BY 
        t.Name,totalspaceMB
    

    数据库空间大小检查索引是否丢失

     SELECT TOP 100  
             ROUND(s.avg_total_user_cost * s.avg_user_impact * ( s.user_seeks  
                                                                 + s.user_scans ),  
                   0) AS [Total Cost] ,  
             s.avg_total_user_cost * ( s.avg_user_impact / 100.0 ) * ( s.user_seeks  
                                                                   + s.user_scans ) AS Improvement_Measure ,  
             DB_NAME() AS DatabaseName ,  
             d.[statement] AS [Table Name] ,  
             equality_columns ,  
             inequality_columns ,  
             included_columns  
     FROM    sys.dm_db_missing_index_groups g  
             INNER JOIN sys.dm_db_missing_index_group_stats s ON s.group_handle = g.index_group_handle  
             INNER JOIN sys.dm_db_missing_index_details d ON d.index_handle = g.index_handle  
     WHERE   s.avg_total_user_cost * ( s.avg_user_impact / 100.0 ) * ( s.user_seeks  
                                                                   + s.user_scans ) > 10  
     ORDER BY [Total Cost] DESC ,  
             s.avg_total_user_cost * s.avg_user_impact * ( s.user_seeks  
                                                           + s.user_scans ) DESC  
    

    查询某个表的列名称、说明、备注、类型等

    SELECT 
        表名       = case when a.colorder=1 then d.name else '' end,
        表说明     = case when a.colorder=1 then isnull(f.value,'') else '' end,
        字段序号   = a.colorder,
        字段名     = a.name,
        标识       = case when COLUMNPROPERTY( a.id,a.name,'IsIdentity')=1 then '√'else '' end,
        主键       = case when exists(SELECT 1 FROM sysobjects where xtype='PK' and parent_obj=a.id and name in (
                         SELECT name FROM sysindexes WHERE indid in( SELECT indid FROM sysindexkeys WHERE id = a.id AND colid=a.colid))) then '√' else '' end,
        类型       = b.name,
        占用字节数 = a.length,
        长度       = COLUMNPROPERTY(a.id,a.name,'PRECISION'),
        小数位数   = isnull(COLUMNPROPERTY(a.id,a.name,'Scale'),0),
        允许空     = case when a.isnullable=1 then '√'else '' end,
        默认值     = isnull(e.text,''),
        字段说明   = isnull(g.[value],'')
    FROM 
        syscolumns a
    left join 
        systypes b 
    on 
        a.xusertype=b.xusertype
    inner join 
        sysobjects d 
    on 
        a.id=d.id  and d.xtype='U' and  d.name<>'dtproperties'
    left join 
        syscomments e 
    on 
        a.cdefault=e.id
    left join 
    sys.extended_properties   g 
    on 
        a.id=G.major_id and a.colid=g.minor_id  
    left join
    sys.extended_properties f
    on 
        d.id=f.major_id and f.minor_id=0
     where      d.name='a_crnh'    --如果只查询指定表,加上此红色where条件,tablename是要查询的表名;去除红色where条件查询说有的表信息
    order by 
        a.id,a.colorder
    

    被锁的表以及如何解锁

    查看被锁表:
    select request_session_id spid,OBJECT_NAME(resource_associated_entity_id) tableName 
    from sys.dm_tran_locks where resource_type='OBJECT' 
    spid 锁表进程 
    tableName 被锁表名
    解锁:
    declare @spid int 
    Set @spid = 57 --锁表进程
    declare @sql varchar(1000)
    set @sql='kill '+cast(@spid as varchar)
    exec(@sql)
    
    EXEC sp_who active --看哪个引起的阻塞,blk blk<>0
    EXEC sp_lock --看锁住了那个资源id,objid objid<>0
    

    查询正在运行的进程

    SELECT
        spid,
        blocked,
        DB_NAME(sp.dbid) AS DBName,
        program_name,
        waitresource,
        lastwaittype,
        sp.loginame,
        sp.hostname,
        a.[Text] AS [TextData],
    sp.stmt_start,
    sp.stmt_end,
        SUBSTRING (
            A. TEXT,
            sp.stmt_start / 2,
            (
                CASE
                WHEN sp.stmt_end = - 1 THEN
                    DATALENGTH(A. TEXT)
                ELSE
                    sp.stmt_end
                END - sp.stmt_start
            ) / 2
        ) AS [current_cmd]
    FROM
        sys.sysprocesses AS sp OUTER APPLY sys.dm_exec_sql_text (sp.sql_handle) AS A
    WHERE
        spid > 50
    ORDER BY
        blocked DESC,
        DB_NAME(sp.dbid) ASC,
        a.[text];
    

    日志查询和清理

    USE tempdb
    GO
    IF OBJECT_ID('dbo.#tbl_DBLogSpaceUsage') IS NOT NULL 
        BEGIN
            DROP TABLE dbo.#tbl_DBLogSpaceUsage
        END
     
    CREATE TABLE dbo.#tbl_DBLogSpaceUsage
        (
          DatabaseName NVARCHAR(128) ,
          LogSize NVARCHAR(25) ,
          LogSpaceUsed NVARCHAR(25) ,
          [Status] TINYINT
        )
     
    INSERT  INTO dbo.#tbl_DBLogSpaceUsage
            EXEC ( 'DBCC SQLPERF(LOGSPACE)'
                )
     
    --查询全部结果:
    SELECT  DatabaseName ,
            LogSize ,
            LogSpaceUsed ,
            [Status]
    FROM    dbo.#tbl_DBLogSpaceUsage order by   convert(FLOAT,LogSize)  
    
    
    --释放空间
    1.右键在清除日志的数据库,如“TestDB”,点击[新建查询(Q)] 
    2.输入以下SQL语句,其中“TestDB”是数据库名称 
    DUMP TRANSACTION TestDB WITH NO_LOG 
    3.执行该SQL,成功后继续以下操作 
    4.右键该数据库节点,点击[任务(T)] -> [收缩(S)] -> [文件(F)] 
    5.在弹出的“收缩文件”对话框中,将“文件类型(T)”选为“日志”,将“收缩操作”选中“在释放未使用的空间前重新组织页(O)” 
    6.在“将文件收缩到(K)”文本框中输入后面提示的最小大小的数值,点击[确定]即可。 
    
    SET NOCOUNT ON 
    DECLARE @LogicalFileName sysname, 
    @MaxMinutes INT, 
    @NewSize INT 
    
    USE tablename -- 要操作的数据库名 
    SELECT @LogicalFileName = 'oa_log', -- 日志文件名 
    @MaxMinutes = 10, -- Limit on time allowed to wrap log. 
    @NewSize = 1 -- 你想设定的日志文件的大小(M) 
    
    -- Setup / initialize 
    DECLARE @OriginalSize int 
    SELECT @OriginalSize = size 
    FROM sysfiles 
    WHERE name = @LogicalFileName 
    SELECT 'Original Size of ' + db_name() + ' LOG is ' + 
    CONVERT(VARCHAR(30),@OriginalSize) + ' 8K pages or ' + 
    CONVERT(VARCHAR(30),(@OriginalSize*8/1024)) + 'MB' 
    FROM sysfiles 
    WHERE name = @LogicalFileName 
    CREATE TABLE DummyTrans 
    (DummyColumn char (8000) not null) 
    
    DECLARE @Counter INT, 
    @StartTime DATETIME, 
    @TruncLog VARCHAR(255) 
    SELECT @StartTime = GETDATE(), 
    @TruncLog = 'BACKUP LOG ' + db_name() + ' WITH TRUNCATE_ONLY' 
    ----收缩数据库日志文件,收到@NewSizeM
    DBCC SHRINKFILE (@LogicalFileName, @NewSize) 
    --备份
    EXEC (@TruncLog) 
    -- Wrap the log if necessary. 
    WHILE @MaxMinutes > DATEDIFF (mi, @StartTime, GETDATE()) -- time has not expired 
    AND @OriginalSize = (SELECT size FROM sysfiles WHERE name = @LogicalFileName) 
    AND (@OriginalSize * 8 /1024) > @NewSize 
    BEGIN -- Outer loop. 
    SELECT @Counter = 0 
    WHILE ((@Counter < @OriginalSize / 16) AND (@Counter < 50000)) 
    BEGIN -- update 
    INSERT DummyTrans VALUES ('Fill Log') 
    DELETE DummyTrans 
    SELECT @Counter = @Counter + 1 
    END 
    EXEC (@TruncLog) 
    END 
    SELECT 'Final Size of ' + db_name() + ' LOG is ' + 
    CONVERT(VARCHAR(30),size) + ' 8K pages or ' + 
    CONVERT(VARCHAR(30),(size*8/1024)) + 'MB' 
    FROM sysfiles 
    WHERE name = @LogicalFileName 
    DROP TABLE DummyTrans 
    SET NOCOUNT OFF 
    

    相关文章

      网友评论

          本文标题:SqlServer表、日志查询

          本文链接:https://www.haomeiwen.com/subject/atvcgftx.html