Microsoft distributes Microsoft SQL Server 2008 fixes as one downloadable file. Because the fixes are cumulative, each new release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2008 fix release.

Symptoms

Consider the following scenario.

  • You enable the data collector.

  • Under a heavy or prolonged workload, when the data collector runs, database maintenance activity on very large databases, such as rebuilding indexes, and updating statistics, may lead to the arithmetic overflow error as follows. This arithmetic overflow error occurs intermittently during the Collect a snapshot of sys.dm_exec_query_stats phase.

Message: SSIS Error Code DTS_E_OLEDBERROR. An OLE DB error has occurred. Error code: 0x80040E57.An OLE DB record is available. Source: "Microsoft SQL Server Native Client 10.0" Hresult: 0x80040E57 Description: "Arithmetic overflow error converting expression to data type int.".

If you increase the data collector logging level to 2 (for example, you run the "exec sp_syscollector_update_collection_set @collection_set_id=<CollectionSetID>,@logging_level = 2" statement), the following error messages are returned:

<Date Time>,SEQ - Capture and analyze query statistics and query plan and text,Error,6569,,,,SSIS Error Code DTS_E_OLEDBERROR. An OLE DB error has occurred. Error code: 0x80040E57.<nl/>An OLE DB record is available. Source: "Microsoft SQL Server Native Client 10.0" Hresult: 0x80040E57 Description: "Arithmetic overflow error converting expression to data type int.".,, <Date Time>,,<Date Time>,,,,OnError,-1071636471 <Date Time>,QueryActivityUpload,Error,6569,,,,SSIS Error Code DTS_E_OLEDBERROR. An OLE DB error has occurred. Error code: 0x80040E57.<nl/>An OLE DB record is available. Source: "Microsoft SQL Server Native Client 10.0" Hresult: 0x80040E57 Description: "Arithmetic overflow error converting expression to data type int.".,, <Date Time>,,<Date Time>,,,,OnError,-1071636471<Date Time>,DFT - Create Interesting Queries Upload Batch,Error,6569,,,,component "ODS - Get current snapshot of dm_exec_query_stats" (16412) failed the pre-execute phase and returned error code 0xC0202009.,, <Date Time>,,<Date Time>,,,,OnError,-1073450982<Date Time>,SEQ - Capture and analyze query statistics and query plan and text,Error,6569,,,,component "ODS - Get current snapshot of dm_exec_query_stats" (16412) failed the pre-execute phase and returned error code 0xC0202009.,, <Date Time>,,<Date Time>,,,,OnError,-1073450982<Date Time>,QueryActivityUpload,Error,6569,,,,component "ODS - Get current snapshot of dm_exec_query_stats" (16412) failed the pre-execute phase and returned error code 0xC0202009.,, <Date Time>,,<Date Time>,,,,OnError,-1073450982

In this scenario, the following statement that is run by SQL Server causes the arithmetic overflow error:

SET NOCOUNT ONDECLARE @p1 datetimeSET @p1 = GETDATE()SELECT     [sql_handle],    statement_start_offset,    statement_end_offset,    -- Use ISNULL here and in other columns to handle in-progress queries that are not yet in sys.dm_exec_query_stats.      -- These values only come from sys.dm_exec_query_stats. If the plan does not show up in sys.dm_exec_query_stats     -- (first execution of a still-in-progress query, visible in sys.dm_exec_requests), these values will be NULL.     MAX (plan_generation_num) AS plan_generation_num,    plan_handle,    MIN (creation_time) AS creation_time,     MAX (last_execution_time) AS last_execution_time,    SUM (execution_count) AS execution_count,    SUM (total_worker_time) AS total_worker_time,    MIN (min_worker_time) AS min_worker_time,           -- NULLable    MAX (max_worker_time) AS max_worker_time,    SUM (total_physical_reads) AS total_physical_reads,    MIN (min_physical_reads) AS min_physical_reads,     -- NULLable    MAX (max_physical_reads) AS max_physical_reads,    SUM (total_logical_writes) AS total_logical_writes,    MIN (min_logical_writes) AS min_logical_writes,     -- NULLable    MAX (max_logical_writes) AS max_logical_writes,    SUM (total_logical_reads) AS total_logical_reads,    MIN (min_logical_reads) AS min_logical_reads,       -- NULLable    MAX (max_logical_reads) AS max_logical_reads,    SUM (total_clr_time) AS total_clr_time,    MIN (min_clr_time) AS min_clr_time,                 -- NULLable    MAX (max_clr_time) AS max_clr_time,    SUM (total_elapsed_time) AS total_elapsed_time,    MIN (min_elapsed_time) AS min_elapsed_time,         -- NULLable    MAX (max_elapsed_time) AS max_elapsed_time,    @p1 AS collection_timeFROM(    SELECT          [sql_handle],        statement_start_offset,        statement_end_offset,        plan_generation_num,        plan_handle,        creation_time,        last_execution_time,        execution_count,        total_worker_time,        min_worker_time,        max_worker_time,        total_physical_reads,        min_physical_reads,        max_physical_reads,        total_logical_writes,        min_logical_writes,        max_logical_writes,        total_logical_reads,        min_logical_reads,        max_logical_reads,        total_clr_time,        min_clr_time,        max_clr_time,        total_elapsed_time,        min_elapsed_time,        max_elapsed_time     FROM sys.dm_exec_query_stats AS q    -- Temporary workaround for VSTS #91422.  This should be removed if/when sys.dm_exec_query_stats reflects in-progress queries.     UNION ALL     SELECT         r.[sql_handle],        r.statement_start_offset,        r.statement_end_offset,        ISNULL (qs.plan_generation_num, 0) AS plan_generation_num,        r.plan_handle,        ISNULL (qs.creation_time, r.start_time) AS creation_time,        r.start_time AS last_execution_time,        1 AS execution_count,        -- dm_exec_requests shows CPU time as ms, while dm_exec_query_stats         -- uses microseconds.  Convert ms to us.         r.cpu_time * 1000 AS total_worker_time,        qs.min_worker_time,     -- min should not be influenced by in-progress queries        r.cpu_time * 1000 AS max_worker_time,        r.reads AS total_physical_reads,        qs.min_physical_reads,  -- min should not be influenced by in-progress queries        r.reads AS max_physical_reads,        r.writes AS total_logical_writes,        qs.min_logical_writes,  -- min should not be influenced by in-progress queries        r.writes AS max_logical_writes,        r.logical_reads AS total_logical_reads,        qs.min_logical_reads,   -- min should not be influenced by in-progress queries        r.logical_reads AS max_logical_reads,        qs.total_clr_time,      -- CLR time is not available in dm_exec_requests        qs.min_clr_time,        -- CLR time is not available in dm_exec_requests        qs.max_clr_time,        -- CLR time is not available in dm_exec_requests        -- dm_exec_requests shows elapsed time as ms, while dm_exec_query_stats         -- uses microseconds.  Convert ms to us.         r.total_elapsed_time * 1000 AS total_elapsed_time,        qs.min_elapsed_time,    -- min should not be influenced by in-progress queries        r.total_elapsed_time * 1000 AS max_elapsed_time    FROM sys.dm_exec_requests AS r     LEFT OUTER JOIN sys.dm_exec_query_stats AS qs ON r.plan_handle = qs.plan_handle AND r.statement_start_offset = qs.statement_start_offset         AND r.statement_end_offset = qs.statement_end_offset     WHERE r.sql_handle IS NOT NULL ) AS query_stats OUTER APPLY sys.dm_exec_sql_text (sql_handle) AS sqlGROUP BY [sql_handle], plan_handle, statement_start_offset, statement_end_offset ORDER BY [sql_handle], plan_handle, statement_start_offset, statement_end_offset

Therefore, if you manually run this statement, you may also receive the following error message:

Msg 8115, Level 16, State 2,Arithmetic overflow error converting expression to data type int

Resolution

The fix for this issue was first released in Cumulative Update 5 for SQL Server 2008 Service Pack 1. For more information about this cumulative update package, click the following article number to view the article in the Microsoft Knowledge Base:

975977 Cumulative update package 5 for SQL Server 2008 Service Pack 1Note Because the builds are cumulative, each new fix release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2008 fix release. Microsoft recommends that you consider applying the most recent fix release that contains this hotfix. For more information, click the following article number to view the article in the Microsoft Knowledge Base:

970365 The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 1 was releasedMicrosoft SQL Server 2008 hotfixes are created for specific SQL Server service packs. You must apply a SQL Server 2008 Service Pack 1 hotfix to an installation of SQL Server 2008 Service Pack 1. By default, any hotfix that is provided in a SQL Server service pack is included in the next SQL Server service pack.

Status

Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.

References

For more information about the Incremental Servicing Model for SQL Server, click the following article number to view the article in the Microsoft Knowledge Base:

935897 An Incremental Servicing Model is available from the SQL Server team to deliver hotfixes for reported problemsFor more information about the naming schema for SQL Server updates, click the following article number to view the article in the Microsoft Knowledge Base:

822499New naming schema for Microsoft SQL Server software update packagesFor more information about software update terminology, click the following article number to view the article in the Microsoft Knowledge Base:

824684 Description of the standard terminology that is used to describe Microsoft software updates

Нужна дополнительная помощь?

Нужны дополнительные параметры?

Explore subscription benefits, browse training courses, learn how to secure your device, and more.

Communities help you ask and answer questions, give feedback, and hear from experts with rich knowledge.