sp_refreshsqlmodule (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics (dedicated SQL pool only)
Updates the metadata for the specified non-schema-bound stored procedure, user-defined function, view, DML trigger, database-level DDL trigger, or server-level DDL trigger in the current database. Persistent metadata for these objects, such as data types of parameters, can become outdated because of changes to their underlying objects. For example, you might see an error like The definition for user-defined data type 'typename' has changed
. Refreshing the metadata for the module that uses the type specified in the error might resolve the problem.
Transact-SQL syntax conventions
sp_refreshsqlmodule
[ @name = ] N'name'
[ , [ @namespace = ] { OBJECT | DATABASE_DDL_TRIGGER | SERVER_DDL_TRIGGER } ]
[ ; ]
Arguments
[ @name = ] N'name'
The name of the stored procedure, user-defined function, view, DML trigger, database-level DDL trigger, or server-level DDL trigger. @name is nvarchar(776), with no default. @name can't be a common language runtime (CLR) stored procedure or a CLR function. @name can't be schema-bound. @name can be a multi-part identifier, but can only refer to objects in the current database.
[ @namespace = ] N'namespace'
The class of the specified module. @namespace is nvarchar(20), with a default of OBJECT
. When @name is a DDL trigger, @namespace is required. Valid inputs are DATABASE_DDL_TRIGGER
and SERVER_DDL_TRIGGER
.
Return code values
0
(success) or a nonzero number (failure).
Remarks
sp_refreshsqlmodule
should be run when changes are made to the objects underlying the module that affect its definition. Otherwise, the module might produce unexpected results when queried or invoked. To refresh a view, you can use either sp_refreshsqlmodule
or sp_refreshview
with the same results.
sp_refreshsqlmodule
doesn't affect any permissions, extended properties, or SET
options that are associated with the object.
To refresh a server-level DDL trigger, execute this stored procedure from the context of any database.
Note
Any signatures that are associated with the object are dropped when you run sp_refreshsqlmodule
.
Permissions
Requires ALTER
permission on the module and REFERENCES
permission on any CLR user-defined types and XML schema collections that are referenced by the object. Requires ALTER ANY DATABASE DDL TRIGGER
permission in the current database when the specified module is a database-level DDL trigger. Requires CONTROL SERVER
permission when the specified module is a server-level DDL trigger.
Additionally, for modules that are defined with the EXECUTE AS
clause, IMPERSONATE
permission is required on the specified principal. Generally, refreshing an object doesn't change its EXECUTE AS
principal, unless the module was defined with EXECUTE AS USER
and the user name of the principal now resolves to a different user than the user at the time the module was created.
Examples
The Transact-SQL code samples in this article use the AdventureWorks2022
or AdventureWorksDW2022
sample database, which you can download from the Microsoft SQL Server Samples and Community Projects home page.
A. Refresh a user-defined function
The following example refreshes a user-defined function. The example creates an alias data type, mytype
, and a user-defined function, to_upper
, that uses mytype
. Then, mytype
is renamed to myoldtype
, and a new mytype
is created that's a different definition. The dbo.to_upper
function is refreshed so that it references the new implementation of mytype
, instead of the old one.
In the first step, create an alias type.
USE AdventureWorks2022;
GO
IF EXISTS (SELECT 'mytype' FROM sys.types WHERE name = 'mytype')
DROP TYPE mytype;
GO
CREATE TYPE mytype FROM NVARCHAR(5);
GO
IF OBJECT_ID('dbo.to_upper', 'FN') IS NOT NULL
DROP FUNCTION dbo.to_upper;
GO
CREATE FUNCTION dbo.to_upper (@a mytype)
RETURNS mytype
WITH ENCRYPTION
AS
BEGIN
RETURN UPPER(@a);
END;
GO
SELECT dbo.to_upper('abcde');
GO
Next, increase the length of the alias type.
sp_rename 'mytype', 'myoldtype', 'userdatatype';
GO
CREATE TYPE mytype FROM NVARCHAR(10);
GO
The function parameter still uses the old type, and fails because of truncation.
SELECT name, TYPE_NAME(user_type_id)
FROM sys.parameters
WHERE object_id = OBJECT_ID('dbo.to_upper');
GO
SELECT dbo.to_upper('abcdefgh'); -- Fails because of truncation
GO
Refresh the function to bind to the renamed type.
EXEC sys.sp_refreshsqlmodule 'dbo.to_upper';
The function parameters are now bound to the correct type and the statement works correctly.
SELECT name, TYPE_NAME(user_type_id)
FROM sys.parameters
WHERE object_id = OBJECT_ID('dbo.to_upper');
GO
SELECT dbo.to_upper('abcdefgh');
GO
B. Refresh a database-level DDL trigger
The following example refreshes a database-level DDL trigger.
USE AdventureWorks2022;
GO
EXEC sys.sp_refreshsqlmodule
@name = 'ddlDatabaseTriggerLog',
@namespace = 'DATABASE_DDL_TRIGGER';
GO
C. Refresh a server-level DDL trigger
The following example refreshes a server-level DDL trigger.
USE master;
GO
EXEC sys.sp_refreshsqlmodule
@name = 'ddl_trig_database',
@namespace = 'SERVER_DDL_TRIGGER';
GO