Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

You may receive a "Permission denied" error message when an application role-based application tries to select records from any one of the system tables in a SQL Server 2005 master database


Symptoms

If an application role-based application tries to select all records from any one of the system tables in a Microsoft SQL Server 2005 master database, you may experience one of the following symptoms:
  • No records are returned.
  • You receive the following error message:
    Permission denied.
For example, this problem may occur if the application uses the following query.
select * from master.dbo.syslogins

↑ Back to the top


Cause

Application role-based applications are designed to work with specific information in a database. These applications cannot access system tables in a master view or in a dynamic management view. These views contain server-level information.

↑ Back to the top


Resolution

To resolve this problem, use certificate-signed procedures to access server-level system tables. Certificate-signed procedures offer the following benefits:
  • You do not have to use trace flags.
  • Less server-level information may be disclosed. Application role-based applications must use stored procedures instead of using general queries. Stored procedures are more likely to return only specific data that is required by the application.

↑ Back to the top


Workaround

To work around this problem, enable global trace flag 4616.

↑ Back to the top


More Information

The following code sample is an example of a certificate-signed procedure.
USE master
GO

CREATE DATABASE approle_db ;
GO

CREATE LOGIN some_login WITH PASSWORD = 'SomePa$$word!' ;
GO

USE approle_db
GO

CREATE USER some_user FOR LOGIN some_login
GO

EXEC sp_addapprole 'an_approle', 'SomeAppRolePa$$word!' ;
GO

---------------------------------------------------------------------
-- This section shows how to use a certificate to authenticate
-- a signed procedure.
---------------------------------------------------------------------

CREATE LOGIN execute_as_login WITH PASSWORD = 'SomePa$$word!' ;
GO

USE master
GO

GRANT VIEW ANY DEFINITION TO execute_as_login ;
GRANT VIEW SERVER STATE TO execute_as_login ;
GO

USE approle_db
GO

CREATE USER execute_as_user FOR LOGIN execute_as_login ;
GO

--
-- You must use EXECUTE AS 'authenticator' here because the application role
-- does not have a server identity. Therefore, the application role cannot use
-- the certificate permissions on the server. Therefore, you
-- need a new execution context to which you can grant
-- the needed VIEW* permissions.
--
CREATE PROC access_server_system_tables
WITH EXECUTE AS 'execute_as_user'
AS
SELECT * FROM master.dbo.syslogins ;
SELECT * FROM master.dbo.sysprocesses ;
GO

GRANT EXECUTE ON access_server_system_tables TO an_approle ;
GO

CREATE CERTIFICATE signing_cert ENCRYPTION BY PASSWORD = 'SomeCertPa$$word'
WITH SUBJECT = 'Signing Cert' ;
GO

BACKUP CERTIFICATE signing_cert TO FILE = 'signing_cert.cer' ;
GO

ADD SIGNATURE TO access_server_system_tables
BY CERTIFICATE signing_cert WITH PASSWORD = 'SomeCertPa$$word' ;
GO

---------------------------------------------------------------------
-- We must create a copy of the signing certificate in the target
-- database. In this case, the target database is the master database.
-- This copy of the signing certificate can vouch
-- for the execution contexts that enter this database from the
-- signed procedure.
---------------------------------------------------------------------
USE master
GO

CREATE CERTIFICATE signing_cert FROM FILE = 'signing_cert.cer' ;
GO

--
-- Because the VIEW* permissions in question are server-level permissions,
-- we need an AUTHENTICATE SERVER on a login-mapped certificate.
--
CREATE LOGIN signing_cert_login FROM CERTIFICATE signing_cert ;
GO

GRANT AUTHENTICATE SERVER TO signing_cert_login
GO


---------------------------------------------------------------------
-- Now you can open a new connection as "some_login" and
-- set the application role. Then, call the "access_server_system_tables"
-- procedure, and obtain verification that you can access server-level information
-- when the application role-based application runs.




---------------------------------------------------------------------


---------------------------------------------------------------------
-- Clean up after the procedure.

---------------------------------------------------------------------
USE master
GO

DROP DATABASE approle_db ;
GO

DROP LOGIN some_login;
GO

DROP LOGIN execute_as_login;
GO

DROP LOGIN signing_cert_login ;
GO

DROP CERTIFICATE signing_cert;
GO

--
-- Make sure to delete the certificate file. For example, delete
-- C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Data\signing_cert.cer
--
EXEC sp_configure 'show advanced options', 1 ;
GO
RECONFIGURE ;
GO
EXEC sp_configure 'xp_cmdshell', 1 ;
GO
RECONFIGURE ;
GO

EXEC xp_cmdshell 'del "C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Data\signing_cert.cer"' ;
GO

EXEC sp_configure 'xp_cmdshell', 0 ;
GO
RECONFIGURE ;
GO


-- ============================================================================
-- - Application role access to server information - Demo usage.sql
--
--
-- This code is companion code that shows an example of application role access
-- to server information by using a certificate-signed procedure.
--
-- ============================================================================

--------------------------------------------------
-- Connect as some_login
--------------------------------------------------
USE approle_db
GO

EXEC sp_setapprole 'an_approle', 'SomeAppRolePa$$word!'
GO

EXEC access_server_system_tables
GO

↑ Back to the top


Keywords: kb, kbprb, kbtshoot, kbsql2005engine

↑ Back to the top

Article Info
Article ID : 906549
Revision : 4
Created on : 8/19/2020
Published on : 8/20/2020
Exists online : False
Views : 291