Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

expected tables in tempdb Expand / Collapse
Author
Message
Posted Friday, February 15, 2008 9:21 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, March 5, 2008 3:59 AM
Points: 4, Visits: 14
May I ask this here?

Our different applications (stored proc) normally remove temp tables in the codes. I know sometimes one or two applications failed for various reasons. Question is: what happened to the temp table it creates if a process failed? Does it mean the specific temp tables a failed stored procedure creates will remain in the tempdb database? And under what ways those tables can be removed?

I heard the tempdb will get automatically re-create when sql server restarts. Does it mean these temp tables will be removed?

If I do not restart sql server, the temp tables will sit there, am I right?
If the temp tables sit there, how do I tell? Can I tell it by table names? If yes, what table names will be shown up when I explore the database in Manangement studio?

Note: the codes in a typical stored procedure of ours reads: create table $tmp ..blah blah blah.

The reason I ask this is because some processes we run are suddenly failing recently. And I suspect it has to do with the tempdb, but at this stage I am not 100% sure. If I examine the tempdb database now, I am seeing table names like #TEMP______________xxxx ( I mean a number of underscores and then xxxxxx, xxxxx are some random characters). I know many of our processes failed multiple times.

So these are some tables in my tempdb now and their names looks like this:
#TEMP____________xxxsxx
#TEMP____________xxsxsxx
..
#TEMP____________xxxxsddxx
and
#5c7dea2943
#4F3D49DCF1
#yyyyyyxx
..
..
#yyyyyyx

All those #yyyyy above are having similar filename format with #5c7dea2943, that is, some hex characters.

Thanks a lot.

Post #456599
Posted Monday, February 18, 2008 1:12 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 8:36 AM
Points: 40,615, Visits: 37,080
There are thee types of 'temp' tables, all stored in the tempDB database.

Global Temp Tables.

Created by CREATE TABLE ##MyTempTable AS ...
They are visible to all sessions. If not explicitly dropped, they are removed when all connections that reference them have disconnected from the server.
Visible in tempDB with the same name as they were created (##MyTempTable )

Local Temporary tables

Created by CREATE TABLE #MyTempTable AS ...
These are visible only to the connection that created them. If not explicity droped, they are dropped as soon as the connection that created them is closed, or the stored proc that created them completes (whichever occurs first)
Visible in tempDB with a name like #MyTempTable____________________________________________________________________________000000000002

Table variables

Created by DECLARE @myTableVar TABLE ...
Visible only in the scope they were created in. Dropped as soon as they go out of scope. Cannot be explicitly dropped.
Visible in tempdb with names like #0DAF0CB0

Does that clear things up?



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
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

Post #456810
Posted Thursday, March 19, 2009 5:55 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, June 26, 2013 1:55 AM
Points: 42, Visits: 116
HI

Wondering if i can jump on the band wagon here. I have a sql 2008 server and i can see in my Tempdb - Temporary Tables section that the table variables #x26779u9 do not get removed . This is starting to clog up my tempdb , how do i remove these tables ?
Post #679312
Posted Thursday, March 19, 2009 2:02 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Yesterday @ 8:45 AM
Points: 173, Visits: 483
I'm having a similar issue. I am seeing these table variables get created, and in my case they are holding millions of rows, they do appear to get dropped, but it leaves behind about 65 gig of information in the tempdb log.

I've been restarting the sql server service to rebuild the tempdb from scratch, but I really need to try to find out why this is filling up the log so fast.
Post #679878
Posted Thursday, March 19, 2009 2:18 PM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, July 24, 2014 2:30 PM
Points: 119, Visits: 346
if you want to clean up tempdb u can schedule this script. it will remove temp tables that are older than 12 hrs. u can schedule it hourly. test it in dev first since i grab it from website

--------------------------------------------

IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = object_id(N’[dbo].[TempTableToKeep]‘) AND OBJECTPROPERTY(id, N’IsUserTable’) = 1)
DROP TABLE [dbo].[TempTableToKeep]
GO
CREATE TABLE [dbo].[TempTableToKeep] (
[TempTable] [varchar] (100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[DateToDelete] [datetime] NOT NULL
) ON [PRIMARY]
GO

IF EXISTS (SELECT name FROM sysobjects WHERE name = N’sp_DropTempTables’ AND type = ‘P’)
DROP PROCEDURE sp_DropTempTables
GO
CREATE PROCEDURE sp_DropTempTables
AS
DECLARE @Cursor AS CURSOR
DECLARE @Name AS VARCHAR(100)
DECLARE @TableName AS SYSNAME
DECLARE @Owner AS VARCHAR(100)
DECLARE @SQL AS NVARCHAR(200)
SET @Cursor = CURSOR SCROLL FOR
SELECT tempdb.dbo.sysobjects.name, tempdb.dbo.sysobjects.*
FROM TempTableToKeep
RIGHT OUTER JOIN tempdb.dbo.sysobjects ON TempTableToKeep.TempTable = tempdb.dbo.sysobjects.name
WHERE ((tempdb.dbo.sysobjects.crdate < DATEADD(hh, -12, GETDATE())) AND (tempdb.dbo.sysobjects.type = ‘U’) AND (TempTableToKeep.DateToDelete < GETDATE())) OR
((tempdb.dbo.sysobjects.crdate < DATEADD(hh, -12, GETDATE())) AND (tempdb.dbo.sysobjects.type = ‘U’) AND (TempTableToKeep.DateToDelete IS NULL))
OPEN @Cursor
FETCH FIRST FROM @Cursor
INTO @Name, @Owner
WHILE (@@FETCH_STATUS = 0)
BEGIN
If (@@FETCH_STATUS = 0)
BEGIN
IF EXISTS(SELECT name FROM tempdb..sysobjects WHERE name = @Name AND type = ‘U’)
BEGIN
SET @SQL = ‘DROP TABLE tempdb..’ + @Name
–PRINT @SQL
EXECUTE sp_executesql @SQL
END
FETCH NEXT FROM @Cursor
INTO @Name
END
END
CLOSE @Cursor
DEALLOCATE @Cursor
GO





Umar Iqbal
Post #679902
Posted Thursday, March 19, 2009 2:19 PM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, July 24, 2014 2:30 PM
Points: 119, Visits: 346
Just qurious what patch you hav eon sql and it it 32 bit or 64 bit?



Umar Iqbal
Post #679904
Posted Thursday, March 19, 2009 2:27 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Yesterday @ 8:45 AM
Points: 173, Visits: 483
64 bit SP2 build 3790
Post #679919
Posted Thursday, March 19, 2009 2:34 PM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, July 24, 2014 2:30 PM
Points: 119, Visits: 346
apply sp3 if you can. is tempdb on raid 1?




Umar Iqbal
Post #679923
Posted Thursday, March 19, 2009 2:47 PM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 8:36 AM
Points: 40,615, Visits: 37,080
umar iqbal (3/19/2009)
if you want to clean up tempdb u can schedule this script. it will remove temp tables that are older than 12 hrs.


Did you test out that script?

TempDB is set up in such a way that a particular connection can only drop temp tables that were created on that connection. if you try to drop a temp table that another connection created, you'll get an error similar to this:

select name from sys.tables
returns - #TEMP_______________________________________________________________________________________________________________000000000003

drop table tempdb..#TEMP_______________________________________________________________________________________________________________000000000003 returns

Cannot drop the table '#TEMP_______________________________________________________________________________________________________________000000000003', because it does not exist or you do not have permission.


The only time that script will work is if people are creating 'permanent' tables in tempDB.

Mike: Check that you don't have lots of open transactions. It also might be SQL caching the table's definitions, if they're frequently used. It's an optimisation in 2005 and higher. If temp tables or table variables (and what you have is a table variable) are frequently used then, instead of dropping them, SQL just 'truncates' them, leaving the definition. It saves the effort of recreating the table next time it's needed.

Are the tables being left with lots of rows in them? How are you checking that (since you can't query any temp table that you didn't create)? You mention 65 GB in the log, that'll just be from tempDB usage, not left over temp tables.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
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

Post #679943
Posted Friday, March 20, 2009 1:39 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, June 26, 2013 1:55 AM
Points: 42, Visits: 116
Sorry i know im in the 2005 forum , but in have a sql 2008 server and there is only sp 1 for the server.
Using DBCC checkDB it returns that all tables have 0 rows , but what else would be slowing down my server . It seems as if there is almost a database or may be table level lock on the tables.
Post #680183
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse