Starting with SQL Server 2000 it's possible to execute a command via the undocumented stored procedure sp_MSForEachTable for each table available in a database, respectively for subsets of the tables. In a previous post I shown how the stored procedure can be used in several scenarios, including how to get the total number of records in each set of tables. However, the code used generates a result set for each table, which makes it difficult to aggregate the information for further processing. In many scenarios, it would be useful to store the result as a temporary or even persisted table.
-- dropping the tables DROP TABLE IF EXISTS #Tables DROP TABLE IF EXISTS #TablesRecordCount -- create a temporary table to store the input list SELECT TableName INTO #Tables FROM (VALUES ('Person.Address') , ('Person.AddressType') , ('Person.BusinessEntity')) DAT(TableName) -- create a temporary table to store the results CREATE TABLE dbo.#TablesRecordCount ( table_name nvarchar(150) NOT NULL , number_records bigint , run_date datetime2(0) , comment nvarchar(255) ) -- getting the number of records for the list of tables into the result table INSERT INTO #TablesRecordCount EXEC sp_MSForEachTable @command1='SELECT ''?'' [Table], COUNT(*) numer_records, GetDate() run_date, ''testing round 1'' comment FROM ?' , @whereand = ' And Object_id In (Select Object_id(TableName) FROM #Tables)' -- reviewing the result SELECT * FROM #TablesRecordCount ORDER BY number_records DESC
The above solution uses two temporary tables, though it can be easily adapted to persist the result in a standard table: just replace the "#" with the schema part (e.g. "dbo."). This can be useful in troubleshooting scenarios, when the code is run at different points in time, eventually for different sets of tables.
The code is pretty simple and can be extended as needed. Unfortunately, there's no guarantee that the sp_MSForEachTable stored procedure will be supported in the next versions of the SQL Server. For example, the stored procedure is not available in SQL databases, respectively in Fabric warehouses. In SQL databases the following error is thrown:
"Msg 2812, Level 16, State 62, Line 1, Could not find stored procedure 'sys.sp_MSForEachTable'."
To test whether the feature works in your environment, it's enough to run a call to the respective stored procedure:
-- retrieve the record count for all tables EXEC sp_MSForEachTable @command1='SELECT ''?'' [Table], COUNT(*) numer_records FROM ?'
Or, you can check whether it works for one table (replace the Person.AddressType table with one from your environment):
-- getting the number of records for the list of tables into another table EXEC sp_MSForEachTable @command1='SELECT ''?'' [Table], COUNT(*) numer_records FROM ?' , @whereand = ' And Object_id = Object_id(''Person.AddressType'')'
The solution could prove to be useful in multiple scenarios, though one should consider also the risk of being forced to rewrite the code when the used stored procedure becomes unavailable. Even if it takes more time to write, a solution based on cursors can be more feasible (see previous post).
Happy coding!
Previous Post <<||>> Next Post
No comments:
Post a Comment