DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

How does AI transform chaos engineering from an experiment into a critical capability? Learn how to effectively operationalize the chaos.

Data quality isn't just a technical issue: It impacts an organization's compliance, operational efficiency, and customer satisfaction.

Are you a front-end or full-stack developer frustrated by front-end distractions? Learn to move forward with tooling and clear boundaries.

Developer Experience: Demand to support engineering teams has risen, and there is a shift from traditional DevOps to workflow improvements.

Related

  • Safeguarding Cloud Databases: Best Practices and Risks Engineers Must Avoid
  • Monitoring and Managing the Growth of the MSDB System Database in SQL Server
  • Engineering Resilience Through Data: A Comprehensive Approach to Change Failure Rate Monitoring
  • Taming Billions of Rows: How Metadata and SQL Can Replace Your ETL Pipeline

Trending

  • Smarter IoT Systems With Edge Computing and AI
  • From Code to Customer: Building Fault-Tolerant Microservices With Observability in Mind
  • Serverless IAM: Implementing IAM in Serverless Architectures with Lessons from the Security Trenches
  • Integrating Cursor and LLM for BDD Testing With Playwright MCP (Model Context Protocol)
  1. DZone
  2. Data Engineering
  3. Databases
  4. Idempotent DB Update Scripts

Idempotent DB Update Scripts

By 
Anders Abel user avatar
Anders Abel
·
Sep. 03, 12 · Interview
Likes (0)
Comment
Save
Tweet
Share
10.8K Views

Join the DZone community and get the full member experience.

Join For Free

An idempotent function gives the same result even if it is applied several times. That is exactly how a database update script should behave. It shouldn’t matter if it is run on or multiple times. The result should be the same.

A database update script should be made to first check the state of the database and then apply the changes needed. If the script is done this way, several operations can be combined into one script that works on several databases despite the databases being at different (possibly unknown) state to start with.

For the database schema itself I usually use Visual Studio 2010 database projects that handles updates automatically (in VS2012 the functionality has been changed significantly). Even with the schema updates handled automatically, there are always things that need manual handling. One common case is lookup tables that need initialization.

Lookup Table Init Script

I use a combination of a temp table and a MERGE clause to init lookup tables.

CREATE TABLE #Colours
(
  ColourId  INT NOT NULL,
  Name      NVARCHAR(10) NOT NULL
)
 
INSERT #Colours VALUES 
(1, N'Red'),
(2, N'Green'),
(3, N'Blue')
 
MERGE Colours dst
USING #Colours src
ON (src.ColourId = dst.ColourId)
WHEN MATCHED THEN
UPDATE SET dst.ColourId = src.ColourId
WHEN NOT MATCHED THEN
INSERT VALUES (src.ColourId, src.Name)
WHEN NOT MATCHED BY SOURCE THEN
DELETE;
 
DROP TABLE #Colours

I think that the temp table approach is great because it gives a clear overview in the script of what the final values will be. It also works regardless of what the current values are. Sometimes it is relevant to keep old values, which can be done by removing the last two lines of the MERGE clause. It is also possible to flag records as inactive instead of deleting them.

MERGE...
...
WHEN NOT MATCHED BY SOURCE THEN
SET dst.Active = 0;

Checking Current State

An idempotent script has to be able to check the current state and adopt its behaviour. The lookup table init script uses the MERGE clause for that, checking the actual values. In most cases it is possible to check the current state by inspecting the values of the table or through the sys meta data views.

If that’s not possible, a separate table can be used to log the scripts run. This method has the advantage of an easy way to check what scripts have been run. The disadvantage is that it violates the DRY Principle by keeping a separate log, which can get out of sync with the actual database schema. What happens when a script is partially run and then fails before writing the log entry? What will happen the next time the script is run?

This is where true idempotent script shines. Whenever there’s a doubt of the current state of the database the entire script can be run again, bringing the database to a known state.

Database

Published at DZone with permission of Anders Abel, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • Safeguarding Cloud Databases: Best Practices and Risks Engineers Must Avoid
  • Monitoring and Managing the Growth of the MSDB System Database in SQL Server
  • Engineering Resilience Through Data: A Comprehensive Approach to Change Failure Rate Monitoring
  • Taming Billions of Rows: How Metadata and SQL Can Replace Your ETL Pipeline

Partner Resources

×

Comments

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • [email protected]

Let's be friends: