How to recompile all stored procedures and table valued functions in SQL Server database?
You can run sp_recompile
on everything by using a cursor to produce ad-hoc SQL for each and run it, if you think that will help:
DECLARE C CURSOR FOR (SELECT [name] FROM sys.objects WHERE [type] IN ('P', 'FN', 'IF'));
DECLARE @name SYSNAME;
OPEN C;
FETCH NEXT FROM C INTO @name;
WHILE @@FETCH_STATUS=0 BEGIN
EXEC sp_recompile @name;
FETCH NEXT FROM C INTO @name;
END;
CLOSE C;
DEALLOCATE C;
or you could produce ad-hoc SQL and run that via EXEC
, takes less code which might be marginally more efficient:
DECLARE @sql NVARCHAR(MAX) = '';
SELECT @sql += 'EXEC sp_recompile '''+[name]+''''+CHAR(10) FROM sys.objects WHERE [type] IN ('P', 'FN', 'IF');
EXEC (@sql);
(though I find this form sometimes throws people due to looking set-based but building the string up iteratively, and not being a standard SQL pattern)
Another set of objects that might be a similar concern here is views. You can similarly mark them as needing to be reassessed to make sure stored plans and other meta-data is not stale with sp_refreshview
, by small modifications to either the cursor or ad-hoc SQL methods shown above:
DECLARE @sql NVARCHAR(MAX) = '';
SELECT @sql += 'EXEC sp_refreshview '''+[name]+''''+CHAR(10) FROM sys.objects WHERE [type] IN ('V');
EXEC (@sql);
The execute plans show 80+ percent of the run time is on a clustered index seek so I don't think there is much more I can do to optimise the stored procedures.
There is sometimes more to optimisation than preferring seeks over scans and so forth, sometimes an index scan is more efficient than many executions of seek operations, and the cost estimates upon which the percent figures you are looking at are calculated are that (estimates) at best (a useful guide but sometimes far from at all accurate).
While "throw more memory at it" can help some database performance issues, at least temporarily, if your bottlenecks are very CPU bound rather than memory and/or IO bound then adding more memory will have very little effect.
If you add memory (even if it's a Hot Added to a VM), and increase Max Server Memory to match, your plan cache will clear out.
That is effectively 'recompiling' all of those things you mentioned, because they won't have a stored plan in cache to re-use. SQL Server will have to build a new one.
You may not have ever set Max Server Memory though. If you're not sure about that, you can run DBCC FREEPROCCACHE
to clear out the plan cache.
You do this at your own risk in production. I can't guarantee the new plan will be better.
Memory doesn't solve every performance problem in SQL Server, and a Seek isn't necessarily the finish line of performance tuning.
If you need help with a specific query, you should ask a separate question.
This solution is based upon the other answer here, but takes schemas into account and considers special characters in the name. It recompiles all procedures, functions and inline functions in all schemas.
create procedure dbo.RecompileAllProcedures
as
begin
declare cur cursor for
(
select quotename(s.name) + '.' + quotename(o.name) as procname
from
sys.objects o
inner join sys.schemas s on o.schema_id = s.schema_id
where o.[type] in ('P', 'FN', 'IF')
);
declare @procname sysname;
open cur;
fetch next from cur into @procname;
while @@fetch_status=0
begin
exec sp_recompile @procname;
fetch next from cur into @procname;
end;
close cur;
deallocate cur;
end;
It can then be called as follows:
exec dbo.RecompileAllProcedures
PS: I'm a big fan of Allman coding style ;)
EDIT: Improved the procedure by using quotename
which is safer in case the name contains a square bracket.