• Hi

    For all you guys looking to find available bytes in a table row for SQL Server 2005 (haven't tested it against previous version but should work) here is a scalar function that accepts a table name and returns teh remaining bytes left for expansion

    Hope it helps !!

    -- ================================================

    -- Template generated from Template Explorer using:

    -- Create Scalar Function (New Menu).SQL

    --

    -- Use the Specify Values for Template Parameters

    -- command (Ctrl-Shift-M) to fill in the parameter

    -- values below.

    --

    -- This block of comments will not be included in

    -- the definition of the function.

    -- ================================================

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    -- =============================================

    -- Author:Ruchir T

    -- Create date: 01/02/2008

    -- Description:returns the number of bytes left to use for creating new columns

    -- =============================================

    CREATE FUNCTION available_tablerowsize

    (

    -- Add the parameters for the function here

    @tablename char(50)

    )

    RETURNS int

    AS

    BEGIN

    -- variables to track fixed and variable column sizes

    DECLARE @num_columns int

    DECLARE @result int

    DECLARE @num_fixed_columns int

    DECLARE @fixed_data_size int

    DECLARE @var_data_size int

    DECLARE @num_var_columns int

    DECLARE @max_var_size int

    DECLARE @null_bitmap_size int

    DECLARE @row_size int

    -- Find the total number of columns

    select @num_columns = count(*)

    from syscolumns,systypes

    where syscolumns.id=object_id(@tablename)

    and syscolumns.xtype=systypes.xtype

    -- Find the size occupied by fixed length columns (Note: not possible to exist outside the 8060 bytes limit)

    select @num_fixed_columns = count(*)

    from syscolumns,systypes

    where syscolumns.id=object_id(@tablename)

    and syscolumns.xtype=systypes.xtype and systypes.variable=0

    select @fixed_data_size = sum(syscolumns.length)

    from syscolumns,systypes

    where syscolumns.id=object_id(@tablename)

    and syscolumns.xtype=systypes.xtype and systypes.variable=0

    -- Find the size occupied by variable length columns within the 8060 page size limit

    -- number of variable length columns

    select @num_var_columns=count(*)

    from syscolumns, systypes

    where syscolumns.id=object_id(@tablename)

    and syscolumns.xtype=systypes.xtype and systypes.variable=1

    -- max size of all variable length columns

    select @max_var_size =max(syscolumns.length)

    from syscolumns,systypes

    where syscolumns.id=object_id(@tablename)

    and syscolumns.xtype=systypes.xtype and systypes.variable=1

    -- calculate variable length storage

    begin

    if @num_var_columns>0

    set @var_data_size=2+(@num_var_columns*2)+@max_var_size

    --set @var_data_size = @num_var_columns*24

    else

    set @var_data_size=0

    end

    -- If there are fixed-length columns in the table, a portion of the row, known as the null bitmap, is reserved to manage column nullability.

    select @null_bitmap_size = 2 + ((@num_columns+7)/8)

    -- Calculate total rowsize

    select @row_size = @fixed_data_size + @var_data_size + @null_bitmap_size + 4

    -- Return the available bytes in the row available for expansion

    select @result = 8060 - @row_size

    RETURN @result

    END

    GO