January 20, 2009 at 2:32 pm
On a development server, we have users who need to be able to modify, execute and view properties of stored procedures. I have tried combinations of permissions such as Alter, Control and View but when they try to view the properties, they receive the following error message:
Property Default Schema is not available for Database "[database_name]". This property may not exist for the object, or may not be retrievable due to insufficient access rights.
Is there some combination aside from sysadmin that allows viewing stored procedure properties?
January 21, 2009 at 2:29 am
Generally, SPs need to be given EXEC permission for those who need to run the SPs.
For this, permission will be provided after creating / altering the SPs like
GRANT EXEC on
- Here PUBLIC can be used to provide EXEC permission to ALL who have access permission to the DB / Server.
You can give the specific permission for the User using:
GRANT
Suresh
January 21, 2009 at 3:32 am
First of all I think you will get better response if you post a 2005 question in the appropriate forum.
Now to your question. There are a couple od roles which by default can view properties of a stored procedure. Sysadmin will work, but is total overkill. db_owner or ddl_admin would be a much better choice.
GRANT VIEW DEFINITION will also work.
But keep in mind that it's not possible to grant any this permission on one specific procedure. The grantee will be able to see definition and properties of all database objects.
[font="Verdana"]Markus Bohse[/font]
January 21, 2009 at 3:54 am
Moved to SS2005 forum
I tend to agree with Markus' advice.
Don't grant this advice to public, however, create your own role.
January 21, 2009 at 6:59 am
I think even a db_owner is an overkill.
What I would suggest is to create a Role with the ddl_Admin as the rights to that particular DB and add the developers who need access to compile Stored procs to that role.
If I was in your shoes, I would never give a Developer access to even read data (forget compiling Stored proc :exclamationmark: ) to a developer in the production Environment.
-Roy
January 21, 2009 at 7:03 am
I agree, they will have view only access to any production objects.
It has been difficult finding the right balance to allow development and debugging without giving too much permission. Thank you for responding!
kay
January 21, 2009 at 8:28 am
Even db_ddladmin is overkill.
Grant CREATE PROC to a role. Put developers in that role.
Grant ALTER SCHEMA on the schema(s) that the developers need to modify stored procedures in to the role.
Grant VIEW DEFINITION on the schema(s) that the developers need to modify stored procedures in to the role.
See if that does the job.
K. Brian Kelley
@kbriankelley
January 21, 2009 at 8:33 am
Brian, I like this way better than my idea..:-)
-Roy
January 21, 2010 at 10:04 am
Easy way to give users/developers view permission to Stored Procedures in SQL 2005:
USE AdventureWorks
GO
CREATE PROCEDURE usp_ExecGrantViewDefinition
(@login VARCHAR(30))
AS
/*
Included Object Types are:
P - Stored Procedure
V - View
FN - SQL scalar-function
TR - Trigger
IF - SQL inlined table-valued function
TF - SQL table-valued function
U - Table (user-defined)
*/
SET NOCOUNT ON
CREATE TABLE #runSQL
(runSQL VARCHAR(2000) NOT NULL)
--Declare @execSQL varchar(2000), @login varchar(30), @space char (1), @TO char (2)
DECLARE @execSQL VARCHAR(2000), @space CHAR (1), @TO CHAR (2)
SET @to = 'TO'
SET @execSQL = 'Grant View Definition ON '
SET @login = REPLACE(REPLACE (@login, '[', ''), ']', '')
SET @login = '[' + @login + ']'
SET @space = ' '
INSERT INTO #runSQL
SELECT @execSQL + schema_name(schema_id) + '.' + [name] + @space + @TO + @space + @login
FROM sys.all_objects s
WHERE type IN ('P', 'V', 'FN', 'TR', 'IF', 'TF', 'U')
AND is_ms_shipped = 0
ORDER BY s.type, s.name
SET @execSQL = ''
Execute_SQL:
SET ROWCOUNT 1
SELECT @execSQL = runSQL FROM #runSQL
PRINT @execSQL --Comment out if you don't want to see the output
EXEC (@execSQL)
DELETE FROM #runSQL WHERE runSQL = @execSQL
IF EXISTS (SELECT * FROM #runSQL)
GOTO Execute_SQL
SET ROWCOUNT 0
DROP TABLE #runSQL
GO
Once this procedure has been created you can grant the permissions as follows.
This example grants view definition to a user "XYZ" in "Adventureworks" Database for all object types that were selected.
USE Adventureworks
GO
EXEC usp_ExecGrantViewDefinition 'XYZ'
GO
Prakash B
January 23, 2010 at 9:08 am
October 19, 2010 at 11:25 pm
-- Create a new role
CREATE ROLE SP_Fn_executor
-- Grant execute to the created role
GRANT EXECUTE TO SP_Fn_executor
The above statement would create a role and grant execute permission on all existing stored procedures and scalar functions.
And as when we create new ones the permission would automatically be given to the Role.
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply