INF: Transaction Log Still Full After DUMP TRAN WITH NO_LOGID: Q184499 
  | 
After receiving an error message 1105 indicating that the transaction log
is full, you may need to issue the following command to truncate the
transaction log:
dump transaction <db> with no_log
If, after running the above command, the transaction log is still reporting
no space available, see the following article in the Microsoft Knowledge
Base to ensure that this is not due to a reporting error:
Q183100 : PRB: Incorrect Log Size Reported in SEM or Performance Monitor
Q110139 : INF: Causes of SQL Transaction Log Filling Up
NOTE: If dumping the transaction log doesn't appear to truncate the majority of your transaction log, you may have an open transaction in the log. To determine whether a transaction has been left open, use DBCC OPENTRAN.
   use <databasename>
   go
   dbcc opentran(<databasename>) 
   Transaction Information for database: pubs
   No active open transactions.
   Replicated Transaction Information:
           Oldest Distributed RID     : (0 , 0)
           Time Stamp                 : 0001 0000000E
           Oldest Non-Distributed RID : (589 , 26)
           Time Stamp                 : 0001 0000363E
   DBCC execution completed. If DBCC printed error messages, see your
   System Administrator. Q89937 : INF: Getting Started with Microsoft SQL Server Replication
   use master
   go
   sp_helpserver 
   name                        network_name                  status      id
   ------------------------------------------------------------------------
   CYGNUS                        CYGNUS                      pub,sub,dis  0 
   select name, category
     from master..sysdatabases
     where name = '<databasename>'
   go
   use <databasename>
   go
   -- The query will return all objects that are published (32) or
   -- replicated (64)
   select name, category
     from sysobjects
     where type = 'U'
       and category & 32 = 32
       or category & 64 = 64 
   name                           category
   ------------------------------------------
   pubs                           0
   (1 row(s) affected) 
   name                           category
   ------------------------------------------
   (0 row(s) affected) 
   use master
   go
   sp_configure 'allow', 1
   go
   reconfigure with override
   go
   begin tran
   update master..sysdatabases set category = 1 where name =
   '<databasename>'
   -- verify that the correct row has been changed by running
   -- select name, category from sysdatabase where name = '<databasename>'
   -- if the correct row is changed then run the following
   commit tran 
   sp_repldone 0, 0, NULL, 0, 0, 1 When page is 0, row is 0, and reset is 1, all replicated transactions in the log are marked as distributed. This is useful when there are replicated transactions in the transaction log that are no longer valid (for example, a published table has been dropped) and you want to truncate the log. For example:
   dump tran <databasename> with no_log 
   dbcc checktable(syslogs) 
   -- Set any object marked for replication as not published or replicated
   update sysobjects set category = category & ~32
   update sysobjects set category = category & ~64
   use master
   go
   -- Set the database as not published
   update sysdatabases set category = 0 where name = '<databasename>'
   sp_configure 'allow',0
   go
   reconfigure with override
   go 
Additional query words: tran duplicate copy
Keywords          : SSrvGen 
Version           : WINNT:6.0,6.5
Platform          : winnt 
Issue type        : kbhowto kbinfo 
Last Reviewed: April 10, 1999