sp_refreshsqlmodule_internal – The user does not have permission to perform this action.
Leave a commentDecember 28, 2016 by Kenneth Fisher
Honestly, I’m only posting this because I had a hard time finding anything posted on this error and I found it somewhat unclear. Here is a quick walk through to produce the error:
-- Create server principal. CREATE LOGIN SQLTest WITH PASSWORD = 'SQLTest'; GO -- Create a database principal with read only access. USE Test; GO CREATE USER SQLTest FROM LOGIN SQLTest; EXEC sp_addrolemember 'db_datareader','SQLTest'; GO -- Create a view. CREATE VIEW dbo.ViewToRefresh AS SELECT * FROM sys.databases; GO
Then login in as SQLTest and run this code:
-- Attempt to refresh the view. USE Test; GO EXEC sp_refreshview 'dbo.ViewToRefresh';
Msg 297, Level 16, State 3, Procedure sp_refreshsqlmodule_internal, Line 74 [Batch Start Line 2]
The user does not have permission to perform this action.
First, if you aren’t aware of what sp_refreshview is you can read a bit more about it here. But basically it’s exactly what it sounds like. It refreshes the view definition.
So what’s up with the error? Well sp_refreshsqlmodule_internal is an undocumented system procedure called by the system procedure sp_refreshsqlmodule which is called by sp_refreshview. You aren’t going to find it in any of the system databases. We just aren’t allowed to see it. Which is singularly unhelpful in trying to track down what’s going on.
Interestingly if SQLTest doesn’t even have read access to the view we get a bit more helpful error.
Msg 15165, Level 16, State 1, Procedure sp_refreshsqlmodule_internal, Line 62 [Batch Start Line 3]
Could not find object ‘dbo.ViewToRefresh’ or you do not have permission.
So how do we fix this? Well, the least permissions fix is to give the database principal alter on the view being refreshed.
GRANT ALTER ON dbo.ViewToRefresh TO SQLTest;
And the refresh will now work with or without read or write access.