TempDB Space issue!

  • Another issue we are facing.

    We have mount point, under the mount point, we have data1, data2, log1, log2, tempdbmdf1, tempdbmdf2, tempdblog1, tempdblog2,.....The tempdb's are pre-sized to say 20GB each, no auto growth set.

    Out of the 20 GB, 15 GB is used for both tempdb...mdf's.

    Getting ticket/alerts saying the tempdb is getting running out space. This has been going on for a while now.

    Here are my questions.

    I had told the AD team to try to fine tune their queries, try to minimize temp tables, temp variables, joins, etc, which will eat up a lot of tempdb space.

    When does the tempdb release space? I know rebooting is one option.(not an option for me)

    What else can you explain about tempdb use?

    Anyone have script to find top 5 queries which will use a lot of tempdb space?

    Anyway, if you don't mind can you guys share your experience with tempDB?

    Thanks,

    SueTons.

    Regards,
    SQLisAwe5oMe.

  • This query should help

    select top 10

    t1.session_id,

    t1.request_id,

    t1.task_alloc,

    t1.task_dealloc,

    (SELECT SUBSTRING(text, t2.statement_start_offset/2 + 1,

    (CASE WHEN statement_end_offset = -1

    THEN LEN(CONVERT(nvarchar(max),text)) * 2

    ELSE statement_end_offset

    END - t2.statement_start_offset)/2)

    FROM sys.dm_exec_sql_text(sql_handle)) AS query_text

    ,(SELECT query_plan from sys.dm_exec_query_plan(t2.plan_handle)) as query_plan

    FROM (Select session_id, request_id,

    sum(internal_objects_alloc_page_count + user_objects_alloc_page_count) as task_alloc,

    sum (internal_objects_dealloc_page_count + user_objects_dealloc_page_count) as task_dealloc

    from sys.dm_db_task_space_usage

    group by session_id, request_id) as t1

    INNER JOIN sys.dm_exec_requests as t2

    ON t1.session_id = t2.session_id

    AND t1.request_id = t2.request_id

    where t1.session_id <> @@SPID

    --AND t1.session_id > 50

    order by t1.task_alloc DESC

    You can find the original for it here:

    http://blogs.msdn.com/b/sqlserverstorageengine/archive/2009/01/12/tempdb-monitoring-and-troubleshooting-out-of-space.aspx

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • Sort operations also hit tempdb. If you have read committed snapshot enabled on any of the databases, they're going to use tempdb. There are just lots and lots of uses for tempdb.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • We have mount point, under the mount point, we have data1, data2, log1, log2, tempdbmdf1, tempdbmdf2, tempdblog1, tempdblog2,.....The tempdb's are pre-sized to say 20GB each, no auto growth set.

    Log files are used sequentially, so there is no real advantage to having multiple log files

    Getting ticket/alerts saying the tempdb is getting running out space. This has been going on for a wile now. When does the tempdb release space? I know rebooting is one option.(not an option for me)

    Objects are destroyed/released from tempdb when the session/spid has completely finished and that spid is destroyed (or reused). In some cases you will notice a session is still active in tempdb and is taking up a lot of space because a developer has written a tempdb-intensive query, it completed, but his spid is still connected to the instance. While the query has completed, the spid is still active, therefore all of the objects/operations that were used in tempdb are still held in the database (they will not go away unless physically dropped (i.e. temp tables)) or the existing connection is closed.

    What else can you explain about tempdb use?

    Please refer to this tempdb whitepaper that offers some great things to bear in mind when dealing with tempdb!

    ______________________________________________________________________________Never argue with an idiot; Theyll drag you down to their level and beat you with experience

  • Thank you. I will read through the tempDB whitepaper article.

    SueTons.

    Regards,
    SQLisAwe5oMe.

Viewing 5 posts - 1 through 4 (of 4 total)

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