expected tables in tempdb

  • 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.

  • 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, 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

    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 ?

  • 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.

  • 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

    :crazy: :alien:

    Umar Iqbal

  • Just qurious what patch you hav eon sql and it it 32 bit or 64 bit?

    :crazy: :alien:

    Umar Iqbal

  • 64 bit SP2 build 3790

  • apply sp3 if you can. is tempdb on raid 1?

    :crazy: :alien:

    Umar Iqbal

  • 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, 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
  • 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.

  • ddorfman (3/20/2009)


    Sorry i know im in the 2005 forum , but in have a sql 2008 server and there is only sp 1 for the server.

    And SP1 for 2008 is still a CTP so should not be on a production server

    Using DBCC checkDB it returns that all tables have 0 rows

    So don't worry about them. There's no performance hit from having lots of tables and, as I mentioned, the caching is an optimisation as recreating the tables very often could (and often did) cause cause problems

    but what else would be slowing down my server .

    Any number of things. Most likely badly written code, inadequate indexes or a combination of both.

    Are certain queries fast while others are slow?

    Are all queries on the server slow?

    Is there blocking?

    Is this poor performance normal, or has it recently started?

    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
  • Thanks for your prompt response.

    At this point im fairly stumped , i could not find any visible locks on tables or any reason for the servers slow down. It just basically ground to a halt.

    I checked via Sp_who2 what processes may be long runnning and cpu intensive and came up with nothing definitive.

    I not a newbie at sql but im struggling to find an effective pragmatic way of finding the root of this performance problem.

    Any advice would be greatly appreciated

  • So there's no blocking? Don't use sp_who2, query the session and requests DMVs directly. Lots more information.

    SELECT * from sys.dm_exec_requests where session_id > 50;

    What are the wait_types and wait_resources that have high wait_times?

    Are all queries on the server slow or just some?

    Did it start recently?

    Try running an UPDATE STATISTICS on all of your tables, see if that makes any difference.

    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

Viewing 13 posts - 1 through 12 (of 12 total)

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