Shrinking the log file does not reduce size

  • I have a database which had mdf size of 350 MB and ldf size 4.9 GB

    When i try to shrink the log file it's not shrinking. I know shrinking a database is not good and it should not be done. But still i am trying to do it for shrinking the log file. The recovery model is set to FULL.

    Then i followed some steps:

    When i run dbcc SQLPerf(logspace) i found that logsize is 4932 MB and Log space used is 98.76%

    So large amount of (98%) of log is using now.

    Then i run this command use <databasename> dbcc loginfo

    Now almost all VLF has status 2 which means all are in use.

    then I tried to take log backup. After log backup also shrinking didnt reduce the size. Then i changed recovery model to simple and then tried shrinking.But this also didn't help. Also i ran dbcc opentran (database)

    and found that no transaction is open now. So what is making the database which does not allow me to shrink the log size.How can i solve this?

  • Please run this:

    select log_reuse_wait_desc from sys.databases where name = 'DBName'

    Is this tempdb or user db?

    After log backup, what is the VSL status? 0 or 2?

  • It's not a tempdb , it is my own user database.

    When i run the query

    select log_reuse_wait_desc from sys.databases where name = 'DBName'

    I got output like

    log_reuse_wait_desc

    REPLICATION

    But i don't have replication set to that database.

  • May be it is backup of a replicated database restored.

    To fix this issue, create a dummy replication and remove it.

    or try this :

    sp_removedbreplication

  • Please read through this: http://www.sqlservercentral.com/articles/Transaction+Log/72488/

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • I tried sp_removedbreplication but it didn't help me to remove it.

    Also under subscription in SMS i cannot see any replication. So from where it came? How it can be removed?

  • Did you read the article I referenced? Specifically the section on replication and if necessary the kb article it links to?

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Hi Gail shaw

    Yes I saw that article. Right now i don't have replication set to the database. I think i had it a year before then i dropped all replication in the server. Now if i check under subscription i dont have any replication. I also checked under database.No where i am not able to find replication. In the link u have mentioned they told to run DBCC OPENTRAN(13) but in my case it returns "No active open transactions."

    Also there is no meaning in running sp_repldone null, null, 0,0,1 as repliaction is not setup. When i run thsi i am getting error like "Unable to execute procedure. The database is not published. Execute the procedure in a database that is published for replication."

    So now please help me.

  • I suggest just deattach and attach it, so replication entry may be removed.

  • Detaching the database worked fine and now replication related problem solved.

    Thank you

  • After detaching and attaching the database when i run query nothing returns. So it is solved.

    But while running dbcc opentran i am getting output like following.

    Transaction information for database 'Reg_test'.

    Replicated Transaction Information:

    Oldest distributed LSN : (0:0:0)

    Oldest non-distributed LSN : (103448:85:1)

    DBCC execution completed. If DBCC printed error messages, contact your system administrator.

    Also if i take the ldf backup and then try to shrink then ldf is not shrinking.I think it is due to the open transaction related to replication.

    So how it can be solved?What does above message means?It's urgent plz help.

  • Not an open transaction (and detaching and attaching would never solve that, detaching and attaching a database won't change anything within the database)

    Either the database has had replication in the past (possibly snapshot replication with the bug mentioned in the article), or has been restored from a database that was replicated. SQL still thinks that everything in the log needs to be replicated but since there's no log reader that will never happen, hence the log is never truncated and will grow until it fills the disk

    If you are absolutely sure that there's no replication, then you can do the following:

    Create a transactional replication publication

    Publish a single article

    Stop the log reader

    run sp_repldone

    Drop the transactional replication publication that you created

    Now run DBCC OPENTRAN again and there should be no reference to distributed and non-distributed LSNs

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • It had replication set in it about 6 months back. But now it is removed.

    As you said i can add replication once again and remove it.But it is a production server so i have to take care while doing it.

    So is there any other method?

    What if i change recovery model to simple and then shrink the log file and then once again change to full recovery model?

    Also if i have to add replication again then i do have some doubts. As this is sql server express so it will act only as subscriber.Also is it ok if i add replication to one new table in that database?

  • IT researcher (5/3/2013)


    As you said i can add replication once again and remove it.But it is a production server so i have to take care while doing it.

    So is there any other method?

    None that works reliably. I suppose you could export the entire DB and recreate it, but that would be rather a large waste of time.

    You just need to replicate one table, can be the smallest table in the DB, doesn't matter. It's just so that SQL will clean up the replication properly

    What if i change recovery model to simple and then shrink the log file and then once again change to full recovery model?

    No effect whatsoever, the log is not waiting for a log backup, it's waiting for replication. Changing the recovery model will leave you a DB in simple recovery waiting for replication to clear the log and shrinkfile will do nothing.

    Please, read the article I references above, most of this is explained in there.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Whether any other tweaks available which can help me to remove replication related data from it? The problem is now i need sql server standard to add a publisher to that database.

Viewing 15 posts - 1 through 15 (of 20 total)

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