This article provides workarounds for the issue that a query against the secondary replica fails with error 2767 "Could not locate statistics".
Symptom
When offloading read-only workloads to a secondary replica of an Always On availability group from a primary replica, you notice that a query against the secondary replica fails with the following error message:
Msg 2767, Level 16, State 1, Procedure sp_table_statistics2_rowset, Line <LineNumber> [Batch Start Line <LineNumber>]
Could not locate statistics '<StatisticsName>' in the system catalogs.
Note
The <StatisticsName> is the statistics generated by a query (AUTO_CREATE_STATISTICS is set to ON) that's running on the primary replica.
Cause
This issue occurs because an active transaction prevents the cache invalidation log record from accessing and refreshing the statistics on the secondary replica.
Workaround
To work around the issue, use one of the following methods as required:
SQL Server
If the issue occurs in SQL Server, run the following command against the secondary replica to synchronize the cached statistics with the statistics on disk:
SQL
DBCC FREESYSTEMCACHE('ALL')
GO
Azure SQL Database
If the issue occurs in Azure SQL Database, run the Invoke-AzSqlDatabaseFailover cmdlet to fail over the readable secondary replica:
This cmdlet fails over the readable secondary replica of the database named <DatabaseName> on the server named <ServerName>.
Azure SQL Managed Instance
If the issue occurs in a Business Critical service tier Azure SQL Managed Instance, run the Invoke-AzSqlInstanceFailover cmdlet to fail over to a read only secondary node:
This cmdlet fails over the readable secondary replica of the Managed Instance named <ManagedInstanceName>.
SQL Server, Azure SQL Database, and Azure SQL Managed Instance
For a more permanent workaround, replace the query-generated statistics with the permanent statistics. Follow these steps:
To determine the table where the query-generated statistics are defined, run the following command against the primary replica by using the statistics name in the error 2767:
SQL
SELECT object_name([object_id]) FROM sys.stats WHEREname='<StatisticsName>'
After running the command, the table name <TableName> is returned.
Run the DBCC SHOW_STATISTICS command by using the name of the table and statistics to determine the column name:
SQL
DBCC SHOW_STATISTICS('<TableName>', '<StatisticsName>')
GO
The following results display the contents of the statistics <StatisticsName> in the table <TableName>, and you can see that the statistics are created in the column <ColumnName> of the table <TableName>.
Name
Updated
<StatisticsName>
<DateTime>
All density
Average Length
Columns
0.5
4
<ColumnName>
To drop the query-generated statistics in the table <TableName> on the primary replica, run the following command:
SQL
DROPSTATISTICS <TableName>.<StatisticsName>
GO
To create the permanent statistics in the column <ColumnName> of the table <TableName> on the primary replica, run the following command:
SQL
CREATESTATISTICS <PermanentStatistics> ON <TableName>(<ColumnName>)
GO
Relational databases store many different types of data for many different types of applications. Some databases have thousands of users and some have just one user. Some tables have tens of rows while others have millions of rows. Some data is unique while other data is duplicated. All of these variables mean that database management systems (DBMSs) need systems to understand the data and the queries that are running against this data to ensure optimum performance. When you perform tune a database, it's im
This article describes the errors and limitations of an availability database in Microsoft SQL Server that is in a Recovery Pending or Suspect state and how to restore the database to full functionality in an availability group.
This article describes the synchronization process, shows you how to calculate some of the key metrics, and gives you the links to some of the common performance troubleshooting scenarios.
Learn how to measure the latency and validate connections for a Transaction Publication in SQL Server using Replication Monitor in SQL Server Management Studio (SSMS), Transact-SQL (T-SQL), or Replication Management Objects (RMO).