January 27, 2013 at 5:16 pm
Comments posted to this topic are about the item Update statistics in parallel
January 28, 2013 at 2:42 am
I've corrected the SQL to include the schema name:
SELECT t.name AS [tname] ,
' update statistics ' + sch.name + '.[' + t.name + '] ' [comando]
FROM sys.tables t
INNER JOIN sys.schemas sch ON sch.schema_id = t.schema_id
LEFT JOIN sys.stats s ON t.object_id = s.object_id
JOIN ( SELECT object_id ,
SUM(rows) rows
FROM sys.partitions
GROUP BY object_id
HAVING SUM(rows) > 0
) pa ON t.object_id = pa.object_id
WHERE ( STATS_DATE(t.object_id, stats_id) IS NULL
OR DATEDIFF(DAY, STATS_DATE(t.object_id, stats_id), GETDATE()) >= 3
)
GROUP BY sch.name ,
t.name
ORDER BY 1
January 28, 2013 at 4:50 am
Good correction !
January 28, 2013 at 1:49 pm
Great job!
One more fix:
SELECT REPLACE(REPLACE(sch.name + '_' + t.name, '[', '_'), ']', '_') AS [tname] ,
' update statistics ' + QUOTENAME(sch.name) + '.' + QUOTENAME(t.name) [comando]
FROM sys.tables t
INNER JOIN sys.schemas sch ON sch.schema_id = t.schema_id
LEFT JOIN sys.stats s ON t.object_id = s.object_id
JOIN ( SELECT object_id ,
SUM(rows) rows
FROM sys.partitions
GROUP BY object_id
HAVING SUM(rows) > 0
) pa ON t.object_id = pa.object_id
WHERE ( STATS_DATE(t.object_id, stats_id) IS NULL
OR DATEDIFF(DAY, STATS_DATE(t.object_id, stats_id), GETDATE()) >= 3
)
GROUP BY sch.name ,
t.name
ORDER BY 1
January 28, 2013 at 4:54 pm
Wow, spinning up SSIS tasks on the fly to take advantage of multithreading. This is exploding my mind at the possibilities.
Thanks for this article, it's a great example to explain this technique. I like that your code considers maximum threads and error handling, I can see the biggest danger might be creating too many packages or falling into some loop of continuous package creation.
Have you recorded some performance metrics of this technique versus using the stored proc to update stats one at a time?
January 29, 2013 at 2:57 am
Thanks to Alexander for the fix.
About performance metrics :
in general, my update statistics runs N times faster than built-in sp_updatestats , where N is number of threads .
I think that N= 5/10 is good for most purposes ... anyway consider that updating statistics in this way is a task that makes heavy use of db resources, to perform his task faster than the dedicated built-in does
February 2, 2013 at 12:08 am
Part of our current daily db maintenance is a sql script that reads through all indexes in a db and determines if they need a reorg or rebuild, or no maintenance required. Problem there is the script runs serially. We have time in our schedule to do this, but it's always great to get things running quicker.
Can anyone think of a reason you couldn't use this same technique to create a list of reorg or rebuild commands, create a sql task for each, and therefore take advantage of the parallelism demonstrated here?
February 5, 2013 at 8:39 am
chadmjordan (2/2/2013)
Part of our current daily db maintenance is a sql script that reads through all indexes in a db and determines if they need a reorg or rebuild, or no maintenance required. Problem there is the script runs serially. We have time in our schedule to do this, but it's always great to get things running quicker.Can anyone think of a reason you couldn't use this same technique to create a list of reorg or rebuild commands, create a sql task for each, and therefore take advantage of the parallelism demonstrated here?
There should be no problem, but consider that rebuilding an index is , in general, much heavier task than update statistics, so I thin you will not be able to use a large number of threads, but you could try with 4/5 , it would speed up your script 4/5 times ...
March 27, 2013 at 12:42 am
Hi Federico, I gave this a try.
We have daily tasks running in our system. Every day at a specific time, we truncate certain tables and repopulate them. We have to update statistics for these tables.
I've written a script which queries sysindexes and finds out the tables which were modified. I integrated that with the script in your article to return tname and comando. This should work very well. However, I get a runtime error. I'm not very good at SSIS. Can you please help me out?
I have attached screenshots of the error. The error says "the source code cannot be displayed". I think the parent package is not able to reference the child package. If I add the child package to the solution and try to execute the child package alone, it works alright.
And when we say app.SaveToXml(packageName + ".dtsx", dataTransferPackage, Nothing)
does the package always get saved within the project directory? How do I deploy this to server? I want to schedule this as a job in the server.
https://sqlroadie.com/
March 27, 2013 at 6:00 am
Arjun Sivadasan (3/27/2013)
Hi Federico, I gave this a try.We have daily tasks running in our system. Every day at a specific time, we truncate certain tables and repopulate them. We have to update statistics for these tables.
I've written a script which queries sysindexes and finds out the tables which were modified. I integrated that with the script in your article to return tname and comando. This should work very well. However, I get a runtime error. I'm not very good at SSIS. Can you please help me out?
I have attached screenshots of the error. The error says "the source code cannot be displayed". I think the parent package is not able to reference the child package. If I add the child package to the solution and try to execute the child package alone, it works alright.
And when we say
app.SaveToXml(packageName + ".dtsx", dataTransferPackage, Nothing)
does the package always get saved within the project directory? How do I deploy this to server? I want to schedule this as a job in the server.
Arjun ,
1) please send me the TSQL code that returns tname and comando , I think the problem is there
2) app.SaveToXml saves to the same directory where is the master DTSX
3) If you want this all to run on the server, you should preferably, as I have done, build a bat file that runs the master DTSX , saved in a dedicated directory on the database server
This will not work if the master DTSX is saved into the SQlSever database , the DTSX must be saved in the filesystem
March 27, 2013 at 6:55 am
Thanks a bunch for the reply. I don't have access to the query right now. There is nothing wrong with the query, I suppose, because the generated dtsx runs fine when executed separately. I guess it has to do with file permissions. I will read up about deployment on server.
https://sqlroadie.com/
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply