Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views

Bullet Working as a team against a common database schema can be a real challenge. Some teams prefer to have their local code connect to a centralized database, but this approach can create many headaches. If I make a schema change to a shared database, but am not ready to check in my code, that can break the site for another developer. For a project like Subtext, it is just not feasible to have a central database.

Instead, I prefer to work on a local copy of the database and propagate changes via versioned change scripts. That way, when I check in my code, I can let others know which scripts to run on their local database when they get latest source code. Of course this can be also be a big challenge as the number of scripts starts to grow and developers are stuck bookkeeping which scripts they have run and which they haven?t.

That is why I always recommend to my teams that we script schema and data changes in an idempotent manner whenever possible. That way, it is much easier to simply batch updates together in a single file (per release for example) and a developer simply runs that single script any time an update is made.

As an example, suppose we have a Customer table and we need to add a column for the customer?s favorite color. I would script it like so:

IF NOT EXISTS 
(
    SELECT * FROM [information_schema].[columns] 
    WHERE   table_name = 'Customer' 
    AND table_schema = 'dbo'
    AND column_name = 'FavoriteColorId'
)
BEGIN
    ALTER TABLE [dbo].[Customer]
    ADD FavoriteColorId int
END

This script basically checks for the existence of the FavoriteColorId column on the table Customer and if it doesn?t exist, it adds it. You can run this script a million times, and it will only make the schema change once.

You?ll notice that I didn?t query against the system tables, instead choosing to lookup the information in an INFORMATION_SCHEMA view named Columns. This is the Microsoft recommendation as they reserve the right to change the system tables at any time. The information views are part of the SQL-92 standard, so they are not likely to change.

There are 20 schema views in all, listed below with their purpose (aggregated from SQL Books). Note that in all cases, only data accessible to the user executing the query against the information_schema views is returned.

Name Returns
CHECK_CONSTRAINTS Check Constraints
COLUMN_DOMAIN_USAGE Every column that has a user-defined data type.
COLUMN_PRIVILEGES Every column with a privilege granted to or by the current user in the current database.
COLUMNS Lists every column in the system
CONSTRAINT_COLUMN_USAGE Every column that has a constraint defined on it.
CONSTRAINT_TABLE_USAGE Every table that has a constraint defined on it.
DOMAIN_CONSTRAINTS Every user-defined data type with a rule bound to it.
DOMAINS Every user-defined data type.
KEY_COLUMN_USAGE Every column that is constrained as a key
PARAMETERS Every parameter for every user-defined function or stored procedure in the datbase. For functions this returns one row with return value information.
REFERENTIAL_CONSTRAINTS Every foreign constraint in the system.
ROUTINE_COLUMNS Every column returned by table-valued functions.
ROUTINES Every stored procedure and function in the database.
SCHEMATA Every database in the system.
TABLE_CONSTRAINTS Every table constraint.
TABLE_PRIVILEGES Every table privilege granted to or by the current user.
TABLES Every table in the system.
VIEW_COLUMN_USAGE Every column used in a view definition.
VIEW_TABLE_USAGE Every table used in a view definition.
VIEWS Every View

When selecting rows from these views, the table must be prefixed with information_schema as in SELECT * FROM information_schema.tables.

Please note that the information schema views are based on a SQL-92 standard so some of the terms used in these views are different than the terms in Microsoft SQL Server. For example, in the example above, I set table_schema = 'dbo'. The term schema refers to the owner of the database object.

Here is another code example in which I add a constraint to the Customer table.

IF NOT EXISTS(
    SELECT * 
    FROM [information_schema].[referential_constraints] 
    WHERE constraint_name = 'FK_Customer_Color' 
      AND constraint_schema = 'dbo'
)
BEGIN
  ALTER TABLE dbo.Customer WITH NOCHECK 
  ADD CONSTRAINT
  FK_Customer_Color FOREIGN KEY
  (
    FavoriteColorId
  ) REFERENCES dbo.Color
  (
    Id
  )
END

I generally don?t go to all this trouble for stored procedures, user defined functions, and views. In those cases I will use Enterprise manager generate a full drop and create script. When a stored procedure is dropped and re-created, you don?t lose data as you would if you dropped and re-created a table that contained some data.

With this approach in hand, I can run an update script with new schema changes confident that I any changes in the script that I have already applied will not be applied again. The same approach works for lookup data as well. Simply check for the data?s existence before inserting the data. It is a little bit more work up front, but it is worth the trouble and schema changes happen less frequently than code or stored procedure changes.

Technorati Tags: ,

What others have said

Requesting Gravatar... Eber Irigoyen Jul 05, 2006 8:41 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
good, now I just need the equivalent for Oracle and I'm good to go =o)
Requesting Gravatar... Joe Brinkman Jul 05, 2006 9:18 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
This is the same method we have used on DotNetNuke and it has served us well as both a development tool and a methodology for upgrading between versions.
Requesting Gravatar... lb Jul 05, 2006 9:37 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
"The information views are part of the SQL-92 standard"

wow! you learn something new every day!

i've got to get out and dabble with non MS databases more... i'd wrongly assumed that the information views were some kind of proprietary 'lets dumb down the developer' set of views that microsoft has grafted on top of the more reliable system tables. turns out i had it more of less *completely* back to front!

cheers Phil!

lb
Requesting Gravatar... Haacked Jul 05, 2006 9:48 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
@Eber - Time to get on the phone and call Larry Ellison and ask for Information_Schema support in ORACLE. As far as I know, it doesn't support it. Though there is probably some equivalent.

@lb - I assumed the same until I started digging into it recently. I've been using the "Columns" view for a long time and never thought to stop and ask, "Are there other views?". I learned a lot in the process.
Requesting Gravatar... DotNetKicks.com Jul 05, 2006 12:50 PM
# Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Trackback from DotNetKicks.com
Requesting Gravatar... Daniel Jul 05, 2006 11:59 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
We use a similar technique, but you must also keep in mind that some scripts may need to be run in a certain order. You wouldn't want an 'ALTER TABLE' to run before a 'CREATE TABLE', for example. We use a custom app and library to package the change scripts in order, grouped by version, in a single XML file. This makes it easy for developers to keep their local db up-to-date, and when we roll out a new version of our app, we use the same XML file and library in our deployment package.

At it's core, the problem is that there hasn't been a first-class development IDE for database development- you can't version them, check them into source control, or deploy them. Microsoft is addressing this in Team System, but to my knowledge there isn't anything being done for us poor non-TS developers.
Requesting Gravatar... Steve Harman Jul 06, 2006 12:59 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Don't forget to use Template Parameters to make those scripts even more robust!

Also, as Phil has pointed out before - you can use the SQL Query Analyzer to replace those parameters just prior to running/testing your script.
Requesting Gravatar... Mischa Kroon Jul 11, 2006 5:34 AM
# All you wanted to know about the INFORMATION_SCHEMA (MsSQL) and then some :)
Information_schema is a part of the information stored in the database and is the preferred gateway to...
Requesting Gravatar... JonGalloway.ToString() Jul 27, 2006 7:56 PM
# [SQL] Scripting backup and restore all databases on a server (Part 2 - Extra CreditM)
In the first post of this series, I discussed scripting database restore statements. It seems simple
Requesting Gravatar... WannaKnow Aug 08, 2006 6:58 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
How do we write something to guard against the column datatype changes, like in your example, if there was a need to change the 'FavoriteColorId' from 'int' to 'varchar(10)'.

I am sure those things happen quite a bit in the course of development.
Requesting Gravatar... Stuzilla Nov 24, 2006 12:25 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Oracle have always let this data be known. They are the DBA views and are taught as part of the admin course. If you are a non dba user, but a schema owner then you have USER views. This data has always been taught by Oracle.
Requesting Gravatar... Ashok Sep 21, 2007 4:51 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Ok Good. How can i change column orders. I want arrange table columns in alphabet order. That table has 25 lakhs of records.
I couldnt do this in design view. Is there any scripts for this?
Requesting Gravatar... K. Scott Allen Feb 01, 2008 1:22 PM
# Versioning Databases ? Change Scripts
After considering the three rules and creating a baseline, an entire team can work with a database whose...
Requesting Gravatar... BusinessRx Reading List Feb 01, 2008 1:32 PM
# Versioning Databases ? Change Scripts
After considering the three rules and creating a baseline , an entire team can work with a database whose
Requesting Gravatar... BlogCoward Feb 04, 2008 1:37 AM
# T-SQL: List of information_schema views
T-SQL: List of information_schema views
Requesting Gravatar... Chi Hoang Feb 05, 2008 10:42 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views

-- Here's the Oracle version
declare
v_table_name varchar2(30) := 'CUSTOMERS';
v_table_exists number(1) := 0;
begin
begin
select 1
into v_table_exists
from user_tables
where table_name = v_table_name;
exception
when NO_DATA_FOUND THEN
dbms_output.put_line ('Creating table ' || v_table_name);
execute immediate 'create table customers (cust_id number, first_name varchar2(100), last_name varchar2(100))';
-- you can insert into version table here
end;
end;
/
Requesting Gravatar... Ish Singh Mar 20, 2008 2:38 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Great article, and we have been using something very similar for many years and thought will share another technique that can be used in addition to this.

Create an extra table in the database that simply keeps track of your database schema version. When I run a script that modifies the schema I simply insert another record and indicating the current database schema version (1.0,1.1,1.2 etc etc). This allows any team member to know the "version" of the database and what scripts they need to run to get their copy of the database to match the current version.

Another advantage is that if your application expects a certain schema, you can program your application to check for the database schema version and ensure that it matches your application's expectations and taking appropriate action (avoid runtime errors).

Also, for oracle here are the views that can be used:
select * from all_tables -- return all tables
select * from all_tab_columns -- returns all columns
select * from all_contraints -- returns all contraints - including fk/pk i think

oops... just realized that Scott Allen has posted a link to his blog that describes the technique I just mentioned above :)

Requesting Gravatar... Gary Brunton Mar 26, 2008 2:08 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
I use a similar approach to what Scott Allen describes. I came across the following article a few years ago that guided me in that direction and it has worked great for me.

http://www.stepwise.com/Articles/2005/DBChanges/
Requesting Gravatar... manish Nov 10, 2008 5:06 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Hey,

Very interesting article and a useful one.

I was wondering if we have a tool that does this for us like enterprise manager do?
Just with a difference that generated script will not have drop and create and instead it will have only alter for all the columns from the new table !!
Requesting Gravatar... Clayton Sep 21, 2010 2:44 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
I think I might stand alone here from looking at the other comments, but I actually disagree with writing re-runnable change scripts in the manner described in the article. My view is that the change scripts should only ever be applied to the database via the automated mechanism that is used to deploy the changes in any environment. That is, the changes should always be applied the same way, whether it's to Dev, Test or Production. And given that, it should always be known what the starting point of the database is, before the scripts are being applied. If the starting point is not known, controlled and validated, then the change cannot be expected to work.
And given that the starting point must be defined, it must also be known whether, say, an object of interest already exists. For example, when changing an existing stored procedure, it must be known that the proc exists, so there is no need to do the common drop/create or create if not exists / alter pattern.
Knowing the starting point, and only have to code to that, means simpler scripts, and less to test.
The key thing is that the developers should never be directly executing the scripts, even on their own local environment. They should be using the scripted mechanism that is created for that purpose.

cheers
Requesting Gravatar... KC Lee Nov 18, 2010 3:34 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
Great Articles - simple and yet very manageable way to maintain database changes. This worked for me and my team for many years too.

However, we are going into a SAAS application design, and we will be doing multi-tenant database design: having multiple databases, schemas, services, and scripts for each customer instance, I am not entirely sure if this method would last us long.
Requesting Gravatar... Simon Needham Feb 01, 2011 10:38 PM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
The INFORMATION_SCHEMA views are great. Someone just needs to tell the SQL Server Management Studio dev team about them!
Requesting Gravatar... Michael Lascuola Feb 17, 2011 4:38 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
These views are great, but when I write a stored proc that uses the view in one database (for instance, master), and try to run that stored proc for each DB, the view returns only the information for master. I have tried using dynamic SQL to USE DB_NAME() for each, but it still does not work. Has anyone else run into this?
Requesting Gravatar... Joel Apr 28, 2011 6:46 AM
# re: Bulletproof Sql Change Scripts Using INFORMATION_SCHEMA Views
There is an important limitation to using information_schema.routines. The routine_definition column is limited to 4000 characters. So if you have a proc longer than that (and many of mine are) you can't use information_schema to search your proc code. Instead, you need to use sys.sql_modules. I don't know if there are similar gotchas in other information_schema views, but this is enough to make me think twice before relying on them.
Requesting Gravatar... Narayana Dec 29, 2011 2:51 PM
# Delete a Column in Table Using INFORMATION_SCHEMA
Can we delete a Column in a Table with out using Alter Command.Can you please give me reply as i need it urgently.

What do you have to say?

(will show your gravatar)
Please add 7 and 1 and type the answer here: