Trans Log Dump

  • Hi,

    Im using the below cursor statement to dump my trans log nightly however I get the following error msg:

    Any suggestions? Thanks for your help.

    select @dbname = RTRIM(@dbname)

    select 'BACKUP LOG ' + @dbname + ' WITH TRUNCATE_ONLY'

    Exec ('dbcc shrinkdatabase (' + @dbname + ',TRUNCATEONLY)')

    [SQLSTATE 01000] (Message 2528) DBCC SHRINKDATABASE: File ID 1 of database ID 7 was skipped because the file does not have enough free space to reclaim....The step failed.

    MCTS: BI 2008, MCITP: BI 2008
    Stay Thirsty My Friends

  • I hope this is not on a production database system.

    Don't shrink the db unless you realy need to !

    SQLServer needed the log-space to support your db !

    Making a log-backup frees logspace internaly, so sqlserver will reuse the physical logs space !

    If you only want to shrink the log-file, don't use shrink database, but use shrink file.

    -- Shrink_TrxLog.SQL

    --INF: How to Shrink the SQL Server 7.0 Transaction Log

    -- SQL7 http://support.microsoft.com/support/kb/articles/q256/6/50.asp?id=256650&SD

    -- SQL7 http://www.support.microsoft.com/kb/256650

    -- SQL2000 http://support.microsoft.com/kb/272318/en-us

    -- SQL2005 http://support.microsoft.com/kb/907511/en-us

    -- select db_name()

    -- select * from sysfiles

    -- THIS SCRIPT IS NOT INTENDED FOR SCHEDULED USAGE !! READ BOL and the urls !!

    SET NOCOUNT ON

    DECLARE @LogicalFileName sysname,

    @MaxMinutes INT,

    @NewSize INT

    -- *** MAKE SURE TO CHANGE THE NEXT 3 LINES WITH YOUR CRITERIA. ***

    SELECT @LogicalFileName = 'logicalname', -- Use sp_helpfile to identify the logical file name that you want to shrink.

    @MaxMinutes = 10, -- Limit on time allowed to wrap log.

    @NewSize = 100 -- in MB

    -- Setup / initialize

    DECLARE @OriginalSize int

    SELECT @OriginalSize = size -- in 8K pages

    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)

    -- Wrap log and truncate it.

    DECLARE @Counter INT,

    @StartTime DATETIME,

    @TruncLog VARCHAR(255)

    SELECT @StartTime = GETDATE(),

    @TruncLog = 'BACKUP LOG ' + db_name() + ' WITH TRUNCATE_ONLY'

    -- Try an initial shrink.

    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) -- the log has not shrunk

    AND (@OriginalSize * 8 /1024) > @NewSize -- The value passed in for new size is smaller than the current size.

    BEGIN -- Outer loop.

    SELECT @Counter = 0

    WHILE ((@Counter < @OriginalSize / 16) AND (@Counter < 50000))

    BEGIN -- update

    INSERT DummyTrans VALUES ('Fill Log') -- Because it is a char field it inserts 8000 bytes.

    DELETE DummyTrans

    SELECT @Counter = @Counter + 1

    END -- update

    EXEC (@TruncLog) -- See if a trunc of the log shrinks it.

    END -- outer loop

    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

    PRINT '*** Perform a full database backup ***'

    SET NOCOUNT OFF

    Johan

    Learn to play, play to learn !

    Dont drive faster than your guardian angel can fly ...
    but keeping both feet on the ground wont get you anywhere :w00t:

    - How to post Performance Problems
    - How to post data/code to get the best help[/url]

    - How to prevent a sore throat after hours of presenting ppt

    press F1 for solution, press shift+F1 for urgent solution 😀

    Need a bit of Powershell? How about this

    Who am I ? Sometimes this is me but most of the time this is me

  • thanks a million.....really helpful

    MCTS: BI 2008, MCITP: BI 2008
    Stay Thirsty My Friends

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply