Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


SQL Server 2005 Stored Procedure Permissions


SQL Server 2005 Stored Procedure Permissions

Author
Message
kwilt
kwilt
SSC Journeyman
SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)

Group: General Forum Members
Points: 95 Visits: 394
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?
Suresh.Utham
Suresh.Utham
Old Hand
Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)Old Hand (354 reputation)

Group: General Forum Members
Points: 354 Visits: 216
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
MarkusB
MarkusB
SSCarpal Tunnel
SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)

Group: General Forum Members
Points: 4449 Visits: 4208
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.

Markus Bohse
Steve Jones
Steve Jones
SSC-Dedicated
SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)

Group: Administrators
Points: 36143 Visits: 18747
Moved to SS2005 forum

I tend to agree with Markus' advice.

Don't grant this advice to public, however, create your own role.

Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
Roy Ernest
Roy Ernest
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2494 Visits: 6852
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 Exclamation Mark ) to a developer in the production Environment.

-Roy
kwilt
kwilt
SSC Journeyman
SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)SSC Journeyman (95 reputation)

Group: General Forum Members
Points: 95 Visits: 394
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
K. Brian Kelley
K. Brian Kelley
Keeper of the Duck
Keeper of the Duck (6.8K reputation)

Group: Moderators
Points: 6816 Visits: 1917
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
Roy Ernest
Roy Ernest
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2494 Visits: 6852
Brian, I like this way better than my idea..:-)

-Roy
Prakash.Bhojegowda MCSE, MCSA...
Prakash.Bhojegowda MCSE, MCSA (SQL 2012)
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 602
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 Bhojegowda MCSE, MCSA (SQL2012)
rojen83
rojen83
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 16
In SQL Server 2005 you can define the execution context of the following user-defined modules: functions (except inline table-valued functions), procedures, queues











_________________
Download Microsoft 2010
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search