Game design, game programming and more

A better way to update SQL stored procedures

A common pattern to manage SQL stored procedures is to drop the current procedure and recreate it. Unfortunately, this doesn’t work if you’re trying to run a high-availability service. Here’s the (broken) drop+create pattern:

-- Delete the stored procedure if it already exists
if exists (
  select * from sys.objects
    where name = N'p_MyProc'
    and type = N'P'
) begin
  drop procedure p_MyProc
end
go

-- Now create it again
create procedure p_MyProc as begin
  print 'go forth and do great things'
end
go

-- And set permissions
grant execute on p_MyProc to SomeRole
go

There’s nothing wrong with this code. Just kick all your users off the server, switch to single user mode, execute the code above and it will work fine.

Oh, what’s that? You’re running a service that needs to be highly available, and you can’t take a maintenance period every time you want to change code?

Using the drop+create method there is obviously a small window of time when the stored procedure does not exist. And as we know from examples like the Seattle monorail crash (see notes at the end of this article), any system that is designed with a built-in flaw will eventually fail because of that flaw.

Here is a better solution:

-- if the procedure does not exist create a placeholder
if not exists (
  select * from sys.objects
    where name = N'p_MyProc'
    and type = N'P'
) begin
  exec('create procedure p_MyProc as
    RAISERROR (''MyProc not defined'', 16, 1);');
end
go

grant execute on p_MyProc to SomeRole
go

-- update stored proc
alter procedure p_MyProc as begin
  print 'go forth and do great things'
end
go

NOTE: Thanks to Justin Wignall for bug-fix to the code above.

This ensures that the stored procedure always exists, and (because SQL is transactional) it is possible to have one caller finishing a call to the old version of the stored procedure while the new version is added and called.

I’ve used this trick successfully for the development of Guild Wars using SQL Server 2000, and later SQL Server 2005, and have not encountered any problems using this technique, even on servers running sustained load of 3000+ transactions per second. In fact the standard operating procedure for our database updates was to update all stored procedures (several hundred of them) every time we performed a deployment.

I assume that similar tricks will work for MySQL and PostgreSQL, and would love to hear from users of those platforms about their experiences.

Update (11/5/2011):

It turns out that MySQL doesn’t support atomic updates of stored procedures; apparently this is a long-standing bug, first filed in 2005 and still not fixed (https://bugs.mysql.com/bug.php?id=9588). And PostgreSQL and Oracle both do properly support this feature with a different SQL syntax: “CREATE OR REPLACE PROCEDURE”.

Notes:

In case you’re wondering about the reference to the Seattle monorail crash, which is a great example of design failure, here’s a bit more information. The original Seattle monorail was built for 1962 World’s Fair, and had two sets of tracks so that two trains could operate side-by-side. The tracks were shortened in the 1988 to end at the newly constructed Westlake Center mall. The new design allowed for an automatic passenger-loading ramp to extend to the trains, but led to the tracks being too close together for two trains to be there at the same time. As you might imagine, this design eventually failed, though it took seventeen years https://www.tecnetinc.com/monorail.html. Of course, when you’re running several thousand SQL transactions per second, such failures are all the more likely.

About Patrick Wyatt

As a game developer with more than 22 years in the industry I have helped build small companies into big ones (VP of Blizzard, Founder of ArenaNet, COO of En Masse Entertainment); lead the design and development efforts for best-selling game series (Warcraft, Diablo, Starcraft, Guild Wars); written code for virtually every aspect of game development (networking, graphics, AI, pathing, sound, tools, installers, servers, databases, ecommerce, analytics, crypto, dev-ops, etc.); designed many aspects of the games I've shipped; run platform services teams (datacenter operations, customer support, billing/accounts, security, analytics); and developed state-of-the-art technologies required to compete in the AAA+ game publishing business.

Comments

  1. Josh Wittner says

    I have to say, this is something that would have bitten my current project if I didn’t run into it here first. Thanks for solving all my problems before I need to!

  2. Brilliant. It seems so self-evident that I hate myself a little now!

  3. Hi Patrick, I realise this is an old post but do you remember what you did to get around the issue of CREATE and ALTER statements needing to be the first statement in a query batch? Wrapping them in an IF doesn’t work on SQL Server.

    • You can use the “go” statement: http://msdn.microsoft.com/en-us/library/ms188037.aspx

      • HI Patrick – Where would you use a go statement? The create has to be wrapped by the ‘if’, a GO anywhere in the middle leading to the CREATE being the first statement in the batch would break the logic.

        I realised after posting my question that this is actually an SQL 2008 and above issue that AFAIK has no solution beyond executing dynamic SQL.

      • I’ve added GO statements in the code above; give it a try!

      • Thanks for looking, the issue is as my original comment which is that the CREATE statement must be the first in a batch. Wrapping in a ‘if’ causes it to be the second statement in that batch. I had thought you had come up with a clever way around this (besides executing an sql string as a single statement which works but makes maintaining code more tricky) that you were obscuring through simplifying your post.

        The error message is

        ‘CREATE/ALTER PROCEDURE’ must be the first statement in a query batch.

        if that clears up what I mean.

        This post

        http://stackoverflow.com/questions/2636105/use-database-dynamically

        talks about having the issue in SQL 2005 yet you appear to not have it – maybe your deployment step executes the whole thing as a single batch?

      • I sent you an email; we can sort it out there and then we can post the answer back here when it is solved.

  4. obama is a liar says

    hey great this article was a bunchof crapola hey Patrick do what you do best and that stick you unit incher up a muslim goats ahole

Speak Your Mind

*