Identity columns near limit

| 2 Comments | 13,073 views
Categories:

VN:F [1.9.17_1161]
Rating: 5.0/5 (5 votes cast)

If your application relies on identity columns, use this metric to measure the number of identity columns that are near to the limit per database. If an identity column is getting close to the limit of the datatype, you need to know so that you can avoid logical problems in your application and SQL Server errors. For example, if you created an IDENTITY column of smallint datatype, if you try to insert more than 32767 rows in the table, you will get the following error:

Server: Msg 8115, Level 16, State 1, Line 1

Arithmetic overflow error converting IDENTITY to data type smallint. Arithmetic overflow occurred.

This is a limitation of the datatype, not the identity.

For more information, see http://vyaskn.tripod.com/sql_server_check_identity_columns.htm

If you want to carry out further analysis, run this query to find which tables have the identity column near to the limit:

WITH CTE_1
AS
(
  SELECT OBJECT_NAME(a.Object_id) as table_name,
         a.Name as columnname,
         CONVERT(bigint, ISNULL(a.last_value,0)) AS last_value,
         Case 
              When b.name = 'tinyint'   Then 255 
              When b.name = 'smallint'  Then 32767 
              When b.name = 'int'       Then 2147483647 
              When b.name = 'bigint'    Then 9223372036854775807
            End As dt_value
    FROM sys.identity_columns a
   INNER JOIN sys.types As b
      ON a.system_type_id = b.system_type_id
),
CTE_2
AS
(
SELECT *, 
       CONVERT(Numeric(18,2), ((CONVERT(Float, last_value) / CONVERT(Float, dt_value)) * 100)) AS "Percent"
  FROM CTE_1
)
SELECT *
  FROM CTE_2
 ORDER BY "Percent" DESC; 
Identity columns near limit, 5.0 out of 5 based on 5 ratings

Metric definition

Metric Name:
Identity columns near limit
Description:

This metric measures the number of identity columns that are near to the limit per database. If an identity column is getting close to the limit of the datatype, you need to know so that you can avoid logical problems in your application and SQL Server errors. For example, if you created an IDENTITY column of smallint datatype, if you try to insert more than 32767 rows in the table, you will get the following error:

Server: Msg 8115, Level 16, State 1, Line 1

Arithmetic overflow error converting IDENTITY to data type smallint. Arithmetic overflow occurred.

This is a limitation of the datatype, not the identity.

For more information, see http://vyaskn.tripod.com/sql_server_check_identity_columns.htm

If you want to carry out further analysis, run this query to find which tables have the identity column near to the limit:

WITH  CTE_1
        AS (SELECT OBJECT_NAME(a.Object_id) AS table_name,
                a.Name AS columnname,
                CONVERT(BIGINT, ISNULL(a.last_value, 0)) AS last_value,
                CASE WHEN b.name = 'tinyint' THEN 255
                     WHEN b.name = 'smallint' THEN 32767
                     WHEN b.name = 'int' THEN 2147483647
                     WHEN b.name = 'bigint' THEN 9223372036854775807
                END AS dt_value
              FROM sys.identity_columns a 
              INNER JOIN sys.types AS b
              ON
                a.system_type_id = b.system_type_id
           ),
      CTE_2
        AS (SELECT *,
                CONVERT(NUMERIC(18, 2), ((CONVERT(FLOAT, last_value)
                / CONVERT(FLOAT, dt_value)) * 100)) AS "Percent"
              FROM CTE_1
           )
  SELECT *
    FROM CTE_2
    ORDER BY "Percent" DESC;
Enter the T-SQL query that will collect data:
WITH  CTE_1
        AS (SELECT OBJECT_NAME(a.Object_id) AS table_name,
                a.Name AS columnname,
                CONVERT(BIGINT, ISNULL(a.last_value, 0)) AS last_value,
                CASE WHEN b.name = 'tinyint' THEN 255
                     WHEN b.name = 'smallint' THEN 32767
                     WHEN b.name = 'int' THEN 2147483647
                     WHEN b.name = 'bigint' THEN 9223372036854775807
                END AS dt_value
              FROM sys.identity_columns a 
              INNER JOIN sys.types AS b
              ON
                a.system_type_id = b.system_type_id
           ),
      CTE_2
        AS (SELECT *,
                CONVERT(NUMERIC(18, 2), ((CONVERT(FLOAT, last_value)
                / CONVERT(FLOAT, dt_value)) * 100)) AS "Percent"
              FROM CTE_1
           )
  SELECT COUNT(*) AS CNT
    FROM CTE_2
    WHERE "Percent" >= 90; -- 90%, threshold
Select instances to collect from:
Select all
Choose databases to collect from:
All user databases
Set collection frequency:
Collect data every day
Use collected or calculated values:
Leave the Use a calculated rate of change between collections check box turned off
Metric collection is:
Enabled

Alert definition

Alert name:
Identity columns near limit
Description:

This alert is raised if an identity column is getting close to the limit of the datatype. You need to know about this so you can avoid logical problems in your application and SQL Server errors. For example, if you created an IDENTITY column of smallint datatype, if you try to insert more than 32767 rows in the table, you will get the following error:

Server: Msg 8115, Level 16, State 1, Line 1

Arithmetic overflow error converting IDENTITY to data type smallint. Arithmetic overflow occurred.

This is a limitation of the datatype, not the identity.

For more information, see http://vyaskn.tripod.com/sql_server_check_identity_columns.htm

If you want to carry out further analysis, run this query to find which tables have the identity column near to the limit:

WITH  CTE_1
        AS (SELECT OBJECT_NAME(a.Object_id) AS table_name,
                a.Name AS columnname,
                CONVERT(BIGINT, ISNULL(a.last_value, 0)) AS last_value,
                CASE WHEN b.name = 'tinyint' THEN 255
                     WHEN b.name = 'smallint' THEN 32767
                     WHEN b.name = 'int' THEN 2147483647
                     WHEN b.name = 'bigint' THEN 9223372036854775807
                END AS dt_value
              FROM sys.identity_columns a 
              INNER JOIN sys.types AS b
              ON
                a.system_type_id = b.system_type_id
           ),
      CTE_2
        AS (SELECT *,
                CONVERT(NUMERIC(18, 2), ((CONVERT(FLOAT, last_value)
                / CONVERT(FLOAT, dt_value)) * 100)) AS "Percent"
              FROM CTE_1
           )
  SELECT *
    FROM CTE_2
    ORDER BY "Percent" DESC;
Raise an alert when the metric value goes:
Above the defined thresholds
Default threshold values:
Set the thresholds as follows:
High:10
Medium:5
Low:0
Note: These thresholds are intended as guideline values. If they seem too high or too low in your environment, replace them with values more suited to your server performance.
Raise an alert when the threshold is passed for:
Enter 1 collection
This alert is:
Enabled
VN:F [1.9.17_1161]
Rating: 5.0/5 (5 votes cast)
  • Gert

    There should be an explanation for the threshold values. What does 5 mean? What does 10 mean? Is that 5% of the values has been used? In that case, is it not a bit early to be warned?

    VA:F [1.9.17_1161]
    Rating: 0 (from 0 votes)
  • Dina Shrestha

    We are using this custom metric on our servers and looks like it does not collect data if SQL is running on a default instance.

    VA:F [1.9.17_1161]
    Rating: 0 (from 0 votes)