June 18, 2009 at 12:27 pm
I have two SQL Server 2005 Standard Edition servers in my development environment that are configured for both Merge and Transactional replication. Server A is the publisher for both, Server B is the subscriber for transactional and a merge participant. One of our developers is trying to update a stored procedure on the publisher and fails with this error:
Msg 21050, Level 16, State 1, Procedure sp_MSmerge_ddldispatcher, Line 12
Only members of the sysadmin fixed server role or db_owner fixed database role can perform this operation. Contact an administrator with sufficient permissions to perform this operation
The developer is a member of db_ddladmin, db_datareader/writer, db_securityadmin, db_accessadmin in the publication database, but is NOT a member of db_owner by design/policy. I have turned off the "Replicate schema changes" option in Subscription Options for both publications, as it appeared in BOL as though any ALTER PROCEDURE statement is replicated when that option is turned on. (We do not replicate any stored procedures in either publication.) Unfortunately, the developer continues to receive this error message.
Is this a Microsoft bug? Is my only recourse (other than executing all SP changes myself) to make developers DBO?
- Jim
~~ Everything in moderation, including moderation. ~~
June 18, 2009 at 1:21 pm
Turns out I may have found the answer, unseemly as it may be. The error message appears to be bogus. The developer went back and checked the stored procedure and it had been updated, despite the error message.
~~ Everything in moderation, including moderation. ~~
April 15, 2010 at 11:41 am
updates, but the change is not replicated to another server. I'm having the same problem.
October 15, 2010 at 4:51 am
Did any of you ever get a resolution to this problem?
October 15, 2010 at 5:19 am
It seems this is a sql design "issue". Once a database is marked for replication ALL objects - whether or not they are replicated - call the sp_MSmerge_ddldispatcher procedure. This SP has an is_member('db_owner') check at the start so it fails if your not. There is a brief discussion on it here...
So it seems there are 2 options
1) You dont give your devs alter permissions in live (probably already in place in larger corps)
2) You let the devs know that the SP will amend but if its replicated then the schema change wont replicate
I'm just going to go with option2 for now as we only replicate tables
January 20, 2011 at 9:17 am
Hello,
I am having the same problem. I had given developers DDL_Admin rights and it was working fine. I just need to setup merge replication for few tables and transactional for other tables. however developer started complaining that they are getting following error while altering procedure (although procedures are getting altered)
Msg 21050, Level 16, State 1, Procedure sp_MSmerge_ddldispatcher, Line 12
Only members of the sysadmin fixed server role or db_owner fixed database role can perform this operation. Contact an administrator with sufficient permissions to perform this operation.
I am not replicating any procedures. I am only replicating few tables.
Not sure why above procedure gets executed and why it needs to check owner.
can someone let me know how to resolve this issue? I do not wish to grant developers more rights.
Jatin Soni
January 22, 2011 at 5:40 am
Found the way to get rid of above error. I am posting solution here so that it will help others who are facing same issues. See the script I have created below.
/*Jatin: following trigger is enabled when replication is setup/altered
If it is Enabled then SQL developer will get following error while they try to
Alter any Procedure in database which is in replication.
Msg 21050, Level 16, State 1, Procedure sp_MSmerge_ddldispatcher, Line 12
Only members of the sysadmin fixed server role or db_owner fixed database role can perform this operation. Contact an administrator with sufficient permissions to perform this operation.
Resolution: Disable this database trigger. Since we are not replicating any procedure or functions,
it will not harm if this trigger do not fire.
*/
IF EXISTS (SELECT is_disabled,* FROM sys.triggers
WHERE parent_class_desc = 'DATABASE'
AND name = N'MSmerge_tr_alterschemaonly'
and is_disabled =0 --0 means DB Trigger is ENABLED
)
Begin
DISABLE TRIGGER [MSmerge_tr_alterschemaonly] ON DATABASE
End
August 21, 2012 at 1:07 pm
I just ran into this with a snapshot replication and a dynamic alter view and had to DISABLE TRIGGER [tr_MStran_alterview] ON DATABASE. I am sure there is a way to grant the proper rights to the underlying triggers. In this case views were not getting replicated so it was ok.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply