Killed clustered index creation, running out of space

  • So, I screwed up. Started a clustered index creation on a large table (20 mil rows, 900 columns, about 145 GB) during lunch time. Half hour later I had to kill it due the phone ringing off the hook. It rolled back quickly, less than 1 min. Bad surprise: about 100GB vanished. I was watching the .mdf growing during the index creation, after killing it, I never got the space back. Now I have only 100GB left on that partition (10%). I checked fragmentation on the table, it is very low, less then 4%. No other indexes right now - I dropped all non clustered indexes before starting the clustered.

    I was afraid recreating the clustered index (this coming weekend) might use up the last 100GB, so I started testing. ON the test system, I let the index creation run for about 1/2 hour, and killed it. Then, I started creating that clustered index. It ran for 1.25 hours, no additional space was used, but didn't get any space back, either. What am I missing here? where did 100Gb go, because a clustered index made of 3 columns (datetime, large int, small int) can;t take up that much space, the whole table is 140GB? One thing I noticed is that the newly created clustered index only has an average page fill of 58%.

    I don't really want to shrink the mdf, but I may have to? Where did 100GB go?

    Thanks!!

  • Creating an index requires at least the size of the index as free space. Plus there's the sort space if you don't have sort in tempDB on. So to create a clustered index on a table of 145 GB, you'd need easily 200GB free space, to put the new index down and to do the sort.

    As for where the space went, it's now free space in the data file, available for any table or index growth that's needed.

    because a clustered index made of 3 columns (datetime, large int, small int) can;t take up that much space, the whole table is 140GB?

    The clustered index is the table, so yes, it would take the full 140GB, create a clustered index on a table that didn't have one, you're recreating the entire table.

    3 columns for a clustered index, bit wider than optimal.

    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
  • For some reason, I thought you need the full space of the table only with ONLINE=ON. It didn't use that much on the test system.

    Looks like I will have to shrink the mdf if I want to create that clustered index..

    The reason for having a 3rd column is because the "uniqueness" factor for the first 2 is very low...

    Thank you!

  • You should also consider specifying "SORT_IN_TEMPDB = ON" on the creation. That usually saves a little space in the db, and, perhaps more importantly, often makes the final table less fragmented.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Marius.D (1/23/2013)


    For some reason, I thought you need the full space of the table only with ONLINE=ON. It didn't use that much on the test system.

    Smaller table on the test server? A build or rebuild of an index needs the full size of that index as free space, more if sort in tempDB is not on

    Looks like I will have to shrink the mdf if I want to create that clustered index..

    Err... so you want to reduce the free space in the database because the index build is running out of space? A little counter-productive perhaps...

    That's like saying that 6 litres of water doesn't fit into a 5 litre bucket, so use a 4 litre bucket instead.

    If some operation runs out of space, you need to grow the file, increase the free space in the file, not shrink it and remove all the free space.

    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
  • Smaller table on the test server? A build or rebuild of an index needs the full size of that index as free space, more if sort in tempDB is not on

    I was looking at available space, that shrunk less than the 140GB. Because there must have had available space in the mdf file that it probably used before expanding the file. I was initially confused by that.

    Err... so you want to reduce the free space in the database because the index build is running out of space? A little counter-productive perhaps...

    That's like saying that 6 litres of water doesn't fit into a 5 litre bucket, so use a 4 litre bucket instead.

    If some operation runs out of space, you need to grow the file, increase the free space in the file, not shrink it and remove all the free space.

    Yes, I understand now, there is no need for shrinking. Which was proven also by re-creating the index on test - the inital mdf file expansion which happened during the aborted index creation was sufficient for re-recreating the index (it did not expand again). Which makes me think I have enough room in production to creat that index this weekend. Looking at the database properties, it says it has 110GB available, and I have 105GB available on the disk partition. Is it safe to assume that having a total of 215GB available, I will have enough room to create that clustered index (144GB)? I believe the database properties shows total space available, including the transaction log file (about 30GB), which means I have (ideally) 215 - 30 = 185 GB available (since I don't intend to shrink the log file). Am I right? Thanks for your help!

  • never mind, teh log size is separat...

    select

    name,

    cast((size/128.0) as int) as TotalSpaceInMB,

    cast((cast(fileproperty(name, 'SpaceUsed') as int)/128.0) as int) as UsedSpaceInMB,

    cast((size/128.0 - cast(fileproperty(name, 'SpaceUsed') AS int)/128.0) as int) as FreeSpaceInMB

    from

    sys.database_files

  • Little tighter than I like, but should be OK. Just specify sort in temp DB (assuming TempDB's on another drive or has decent free space)

    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
  • TempDB seems to be always full, maybe I'll reboot first.. thanks!

  • Marius.D (1/24/2013)


    TempDB seems to be always full, maybe I'll reboot first.. thanks!

    Then you've got a second issue that needs addressed! 🙂

    Increase the size of tempdb until you have "slack" except when under the highest usage conditions.

    You do not want tempdb to dynamically expand at all it possible, and it should definitely not be a common thing.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Well, it's not full, sorry, it just doesn't have enough room available (81 out of 84GB). It is not set to autogrow, it takes up 99% of a disk partition, logfile is on different partition...

  • Marius.D (1/24/2013)


    Well, it's not full, sorry, it just doesn't have enough room available (81 out of 84GB).

    That looks pretty full to me.

    I think, before worrying about indexes, you might want to address the storage issue, get more drives, expand storage.

    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
  • So you're saying since I can't use tempdb for sorting because I only have 81GB available, I should take care of that first..

    Well, this is a large table, 99% of the tables would fit into Tempdb.

  • You have inadequate space on the TempDB drive and the user database drive to rebuild a clustered index (yes, rebuilding requires the same free space as creating it), that's a pretty clear indication that you are low on disk space, when regular maintenance will run a drive out of space.

    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
  • An extraordinarily large table (which I'll abbreviate "xlt" for convenience) can indeed cause unusual issues.

    If you use tempdb, it needs (lots of) extra disk space, which basically can't be freed while SQL is running.

    If you don't use tempdb, you might not have any good choice except to test for avail. space and explicitly grow the db file(s) containing the xlt before doing the rebuild if necessary. You'll want to make sure IFI is set on for that if at all possible (hopefully it's already on all the time anyway).

    But then it will be extremely difficult to shrink the db to regain any of that disk space either, as that can fragment that xlt you just rebuilt.

    Ouch! The disk space is basically gone either way :(.

    Given that, I prefer to increase tempdb to the point where it can handle the xlt rebuild. That way, if any new xlt(s) are ever added, the tempdb space handles rebuilding any of them (you just can't rebuild more than one of the xlt's at the same time). And the rebuild results are often better, resulting in a less fragmented xlt, which was the point of the rebuild in the first place.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

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

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