├── .dir-locals.el ├── .travis.yml ├── LICENSE.txt ├── test.sh ├── README.md └── migrations.sql /.dir-locals.el: -------------------------------------------------------------------------------- 1 | ;;; Directory Local Variables 2 | ;;; For more information see (info "(emacs) Directory Variables") 3 | 4 | ((sql-mode 5 | (sql-product . postgres))) 6 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | services: 2 | - postgresql 3 | 4 | addons: 5 | postgresql: "9.5" 6 | 7 | script: 8 | ./test.sh 9 | 10 | # Local Variables: 11 | # indent-tabs-mode: nil 12 | # coding: utf-8 13 | # End: 14 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- 1 | Copyright (C) 2017 Steve Purcell. 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining 4 | a copy of this software and associated documentation files (the 5 | "Software"), to deal in the Software without restriction, including 6 | without limitation the rights to use, copy, modify, merge, publish, 7 | distribute, sublicense, and/or sell copies of the Software, and to 8 | permit persons to whom the Software is furnished to do so, subject to 9 | the following conditions: 10 | 11 | The above copyright notice and this permission notice shall be 12 | included in all copies or substantial portions of the Software. 13 | 14 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 15 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 16 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND 17 | NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE 18 | LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION 19 | OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION 20 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 21 | -------------------------------------------------------------------------------- /test.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh -e 2 | 3 | export PGDATABASE=migration-test 4 | THISDIR=$(dirname "$0") 5 | 6 | reset() { 7 | dropdb --if-exists "$PGDATABASE" 8 | createdb "$PGDATABASE" 9 | } 10 | 11 | run_migrations() { 12 | psql -q -v ON_ERROR_STOP=1 -1f "$1" 13 | } 14 | 15 | assert() { 16 | temp=$(mktemp) 17 | cat <<'EOF' > "$temp" 18 | DO 19 | $body$ 20 | BEGIN 21 | EOF 22 | cat >> "$temp" 23 | cat <<'EOF' >> "$temp" 24 | END 25 | $body$; 26 | EOF 27 | psql -q -v ON_ERROR_STOP=1 -f "$temp" 28 | } 29 | 30 | fail() { 31 | echo "TEST FAILED" >&2 32 | exit 1; 33 | } 34 | 35 | announce() { 36 | echo 37 | echo "---------------------------------------------------" 38 | echo "$@" 39 | echo "---------------------------------------------------" 40 | } 41 | 42 | test_file=$(mktemp) 43 | cat "$THISDIR/migrations.sql" > "$test_file" 44 | 45 | reset 46 | run_migrations "$test_file" 47 | 48 | announce "Checking initial state" 49 | assert <<'EOF' 50 | ASSERT (EXISTS (SELECT FROM pg_catalog.pg_proc WHERE proname = 'apply_migration')); 51 | ASSERT (NOT EXISTS (SELECT FROM pg_catalog.pg_tables WHERE tablename = 'applied_migrations' AND schemaname = 'public')); 52 | EOF 53 | 54 | announce "Migrating to create a simple table." 55 | cat <<'EOF' >> $test_file 56 | SELECT apply_migration('create_foo', $$ 57 | CREATE TABLE foo (); 58 | $$); 59 | EOF 60 | run_migrations "$test_file" 61 | 62 | announce "Checking migration ran and was recorded" 63 | assert <<'EOF' 64 | ASSERT (EXISTS (SELECT 1 FROM applied_migrations WHERE identifier = 'create_foo')); 65 | ASSERT (EXISTS (SELECT FROM pg_catalog.pg_tables WHERE tablename = 'foo' AND schemaname = 'public')); 66 | EOF 67 | 68 | announce "Re-running to check idempotency" 69 | run_migrations "$test_file" 70 | assert <<'EOF' 71 | ASSERT (1 = (SELECT COUNT(1) FROM applied_migrations)); 72 | EOF 73 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Build Status](https://travis-ci.org/purcell/postgresql-migrations.svg?branch=master)](https://travis-ci.org/purcell/postgresql-migrations) 2 | Support me 3 | 4 | ## Simple Schema Migrations for PostgreSQL 5 | 6 | ### About 7 | 8 | This repository, which began as a simple Gist, provides a tiny starter 9 | kit and instructions for safely performing schema migrations on a 10 | PostgreSQL database. It works by providing a PLPGSQL procedure which 11 | can execute a chunk of SQL and then note it as having been executed, 12 | so that it will not be executed again the next time. 13 | 14 | We're actively using this in production over at NEC Smart Cities with 15 | great success, so it is now somewhat proven and maintained. 16 | 17 | ### Installation 18 | 19 | Copy `migrations.sql` to your project. Add migrations to the end of 20 | that file in the form of calls to `apply_migration`, as shown in the 21 | examples in that file. To apply all pending migrations, including 22 | bootstrapping the migration function and its `migrations` table, run 23 | the file against your database in a single transaction with psql, or 24 | via your database connection adaptor. 25 | 26 | ``` 27 | psql -v ON_ERROR_STOP=1 -1f -- migrations.sql yourdbname 28 | ``` 29 | 30 | You should generally arrange to run migrations as the database owner 31 | (or even the super-user), and your applications should use 32 | less-privileged users. 33 | 34 | ### Author 35 | 36 | This software was written by 37 | [Steve Purcell](https://github.com/purcell). 38 | 39 | ### License and copyright 40 | 41 | MIT license. 42 | 43 |
44 | 45 | Author links: 46 | 47 | [💝 Support this project and my other Open Source work](https://www.patreon.com/sanityinc) 48 | 49 | [💼 LinkedIn profile](https://uk.linkedin.com/in/stevepurcell) 50 | 51 | [✍ sanityinc.com](http://www.sanityinc.com/) 52 | -------------------------------------------------------------------------------- /migrations.sql: -------------------------------------------------------------------------------- 1 | -- This file provides a method for applying incremental schema changes 2 | -- to a PostgreSQL database. 3 | 4 | -- Add your migrations at the end of the file, and run "psql -v ON_ERROR_STOP=1 -1f 5 | -- migrations.sql yourdbname" to apply all pending migrations. The 6 | -- "-1" causes all the changes to be applied atomically 7 | 8 | -- Most Rails (ie. ActiveRecord) migrations are run by a user with 9 | -- full read-write access to both the schema and its contents, which 10 | -- isn't ideal. You'd generally run this file as a database owner, and 11 | -- the contained migrations would grant access to less-privileged 12 | -- application-level users as appropriate. 13 | 14 | -- Refer to https://github.com/purcell/postgresql-migrations for info and updates 15 | 16 | -------------------------------------------------------------------------------- 17 | -- A function that will apply an individual migration 18 | -------------------------------------------------------------------------------- 19 | DO 20 | $body$ 21 | BEGIN 22 | IF NOT EXISTS (SELECT FROM pg_catalog.pg_proc WHERE proname = 'apply_migration') THEN 23 | CREATE FUNCTION apply_migration (migration_name TEXT, ddl TEXT) RETURNS BOOLEAN 24 | AS $$ 25 | BEGIN 26 | IF NOT EXISTS (SELECT FROM pg_catalog.pg_tables WHERE tablename = 'applied_migrations') THEN 27 | CREATE TABLE applied_migrations ( 28 | identifier TEXT NOT NULL PRIMARY KEY 29 | , ddl TEXT NOT NULL 30 | , applied_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() 31 | ); 32 | END IF; 33 | LOCK TABLE applied_migrations IN EXCLUSIVE MODE; 34 | IF NOT EXISTS (SELECT 1 FROM applied_migrations m WHERE m.identifier = migration_name) 35 | THEN 36 | RAISE NOTICE 'Applying migration: %', migration_name; 37 | EXECUTE ddl; 38 | INSERT INTO applied_migrations (identifier, ddl) VALUES (migration_name, ddl); 39 | RETURN TRUE; 40 | END IF; 41 | RETURN FALSE; 42 | END; 43 | $$ LANGUAGE plpgsql; 44 | END IF; 45 | END 46 | $body$; 47 | 48 | -------------------------------------------------------------------------------- 49 | -- Example migrations follow, commented out 50 | -------------------------------------------------------------------------------- 51 | 52 | -- -- Give each migration a unique name: 53 | -- SELECT apply_migration('create_things_table', 54 | -- $$ 55 | -- -- SQL to apply goes here 56 | -- CREATE TABLE things ( 57 | -- name TEXT 58 | -- ); 59 | -- $$); 60 | 61 | -- -- Add more migrations in the order you'd like them to be applied: 62 | -- SELECT apply_migration('alter_things_table', 63 | -- $$ 64 | -- -- You can place not just one statement... 65 | -- ALTER TABLE things ADD number INTEGER; 66 | -- -- ...but multiple in here. 67 | -- ALTER TABLE things ALTER name SET NOT NULL; 68 | -- -- All statements will be run in a transaction. 69 | -- $$); 70 | --------------------------------------------------------------------------------