├── .github └── workflows │ ├── release.yml │ └── test.yml ├── .gitignore ├── Dockerfile ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── latest-changes.md ├── metagration.png ├── metagration.svg ├── sql └── metagration.sql ├── test.sh └── test ├── core.sql ├── test.sql └── verify.sql /.github/workflows/release.yml: -------------------------------------------------------------------------------- 1 | name: Release 2 | on: 3 | push: 4 | tags: [v*] 5 | jobs: 6 | release: 7 | name: Release on GitHub and PGXN 8 | environment: test 9 | runs-on: ubuntu-latest 10 | container: pgxn/pgxn-tools 11 | env: 12 | GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} 13 | PGXN_USERNAME: ${{ secrets.PGXN_USERNAME }} 14 | PGXN_PASSWORD: ${{ secrets.PGXN_PASSWORD }} 15 | steps: 16 | - name: Check out the repo 17 | uses: actions/checkout@v2 18 | - name: Bundle the Release 19 | id: bundle 20 | run: pgxn-bundle 21 | - name: Release on PGXN 22 | run: pgxn-release 23 | - name: Create GitHub Release 24 | id: release 25 | uses: actions/create-release@v1 26 | with: 27 | tag_name: ${{ github.ref }} 28 | release_name: Release ${{ github.ref }} 29 | body_path: latest-changes.md 30 | - name: Upload Release Asset 31 | uses: actions/upload-release-asset@v1 32 | with: 33 | upload_url: ${{ steps.release.outputs.upload_url }} 34 | asset_path: ./${{ steps.bundle.outputs.bundle }} 35 | asset_name: ${{ steps.bundle.outputs.bundle }} 36 | asset_content_type: application/zip 37 | -------------------------------------------------------------------------------- /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: Tests 2 | 3 | on: push 4 | 5 | jobs: 6 | tests: 7 | runs-on: ubuntu-latest 8 | steps: 9 | - uses: actions/checkout@v2 10 | - name: Run tests 11 | run: | 12 | ./test.sh 13 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Prerequisites 2 | *.d 3 | 4 | # Object files 5 | *.o 6 | *.ko 7 | *.obj 8 | *.elf 9 | 10 | # Linker output 11 | *.ilk 12 | *.map 13 | *.exp 14 | 15 | # Precompiled Headers 16 | *.gch 17 | *.pch 18 | 19 | # Libraries 20 | *.lib 21 | *.a 22 | *.la 23 | *.lo 24 | 25 | # Shared objects (inc. Windows DLLs) 26 | *.dll 27 | *.so 28 | *.so.* 29 | *.dylib 30 | 31 | # Executables 32 | *.exe 33 | *.out 34 | *.app 35 | *.i*86 36 | *.x86_64 37 | *.hex 38 | 39 | # Debug files 40 | *.dSYM/ 41 | *.su 42 | *.idb 43 | *.pdb 44 | 45 | # Kernel Module Compile Results 46 | *.mod* 47 | *.cmd 48 | .tmp_versions/ 49 | modules.order 50 | Module.symvers 51 | Mkfile.old 52 | dkms.conf 53 | -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | FROM postgres:14 2 | RUN apt-get update && apt-get install -y postgresql-14-pgtap postgresql-plpython3-14 3 | RUN mkdir "/metagration" 4 | RUN mkdir "/archivedir" 5 | WORKDIR "/metagration" 6 | COPY . . 7 | COPY sql/metagration.sql /docker-entrypoint-initdb.d/ 8 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Michel Pelletier 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "metagration", 3 | "abstract": "Migrate Postgres with Postgres", 4 | "description": "This extension provides a powerful Postgres migration tool written in Postgres itself.", 5 | "version": "1.0.5", 6 | "maintainer": [ 7 | "Michel Pelletier " 8 | ], 9 | "license": "postgresql", 10 | "provides": { 11 | "metagration": { 12 | "abstract": "Migrate Postgres with Postgres", 13 | "file": "sql/metagration.sql", 14 | "docfile": "README.md", 15 | "version": "1.0.5" 16 | } 17 | }, 18 | "prereqs": { 19 | "runtime": { 20 | "requires": { 21 | "PostgreSQL": "11.0.0" 22 | } 23 | } 24 | }, 25 | "resources": { 26 | "bugtracker": { 27 | "web": "https://github.com/michelp/metagration/issues/" 28 | }, 29 | "repository": { 30 | "url": "git://github.com/michelp/metagration.git", 31 | "web": "https://github.com/michelp/metagration/", 32 | "type": "git" 33 | } 34 | }, 35 | "generated_by": "Michel Pelletier", 36 | "meta-spec": { 37 | "version": "1.0.0", 38 | "url": "https://pgxn.org/meta/spec.txt" 39 | }, 40 | "tags": [ 41 | "migration", 42 | "replication", 43 | "pgtap" 44 | ] 45 | } 46 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = $(shell grep -m 1 '"name":' META.json | \ 2 | sed -e 's/[[:space:]]*"name":[[:space:]]*"\([^"]*\)",/\1/') 3 | EXTVERSION = $(shell grep -m 1 '[[:space:]]\{8\}"version":' META.json | \ 4 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 5 | DISTVERSION = $(shell grep -m 1 '[[:space:]]\{3\}"version":' META.json | \ 6 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 7 | 8 | DATA = $(wildcard sql/*--*.sql) 9 | TESTS = $(wildcard test/sql/*.sql) 10 | PG_CONFIG ?= pg_config 11 | 12 | PGXS := $(shell $(PG_CONFIG) --pgxs) 13 | include $(PGXS) 14 | 15 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 16 | 17 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 18 | cp $< $@ 19 | 20 | dist: 21 | git archive --format zip --prefix=$(EXTENSION)-$(DISTVERSION)/ -o $(EXTENSION)-$(DISTVERSION).zip HEAD 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Tests](https://github.com/michelp/metagration/actions/workflows/test.yml/badge.svg)](https://github.com/michelp/metagration/actions/workflows/test.yml) 2 | 3 |
4 | 5 |

6 | 7 |

8 | 9 | # Metagration: Logical PostgreSQL Migration 10 | 11 | Migrating logically replicated PostgreSQL databases is a delicate 12 | dance of applying the right script at the right time, and enduring 13 | possible downtime making sure replicas are correctly up to date. 14 | Consider the [warnings from the 15 | documentation](https://www.postgresql.org/docs/current/logical-replication-restrictions.html): 16 | 17 | - The database schema and DDL commands are not replicated. The 18 | initial schema can be copied by hand using pg_dump 19 | --schema-only. Subsequent schema changes would need to be kept in 20 | sync manually. 21 | 22 | Metagration is a PostgreSQL migration tool written in PostgreSQL. 23 | Metagration "up/down" scripts are stored procedures and applied 24 | in-database by the database. Creating and managing metagrations and 25 | actually running them are *completely decoupled*. 26 | 27 | Metagrations can be managed and replicated like any other data in your 28 | database using whatever favorite tool you are already familar with. 29 | Using tools like [pglogical](https://github.com/2ndQuadrant/pglogical) 30 | you can then apply metagrations across logically replicated cluster at 31 | the exact same point in time in the WAL stream. Metagration keeps 32 | track of [restore 33 | points](https://www.postgresql.org/docs/current/functions-admin.html#FUNCTIONS-ADMIN-BACKUP) 34 | before all changes so entire clusters can be 35 | [Point-In-Time-Recovered](https://www.postgresql.org/docs/14/continuous-archiving.html) 36 | to the same point in the transcation log, avoiding migration induced 37 | conflict errors. 38 | 39 | **Metagration has support for 100% of PostgreSQL's features, because it 40 | *is* PostgreSQL**: 41 | 42 | - Up/Down scripts are stored procedures in any pl language. 43 | 44 | - No external tools, any PostgreSQL client can manage metagrations. 45 | 46 | - Cloud-friendly single ~470 line SQL file for any PostgreSQL >= 11. 47 | 48 | - One simple function for new SQL scripts. 49 | 50 | - Procedures can be transactional, and transaction aware. 51 | 52 | - Generates Point In Time Recovery restore points before migration. 53 | 54 | - Metagrations can export/import to/from SQL files. 55 | 56 | - Metagrations are just rows so `pg_dump/pg_restore` them. 57 | 58 | - Can use pgTAP for powerful migration verification. 59 | 60 | - Postgres docker container entrypoint friendly. 61 | 62 | ## Intro 63 | 64 | Metagrations are DDL change scripts wrapped in PostgreSQL stored 65 | procedures run in a specific order either "up" or "down". A 66 | metagration is a script defined entirely within the database, there is 67 | no external migration tool or language. 68 | 69 | Metagration `script`s are what move the database from one revision to 70 | the next. Each script has a forward "up" procedure, and optionally a 71 | backward "down" procedure to undo the "up" operation. Script 72 | procedures can be written in *any* supported stored procedure 73 | language. Metagration strictly enforces the revision order of the 74 | scripts applied. 75 | 76 | Metagration comes with a simple create function for writing fast up 77 | and down scripts in plpgsql, which often look exactly like their SQL 78 | counterparts: 79 | 80 | # SELECT metagration.new_script( 81 | 'CREATE TABLE public.foo (id bigserial);', 82 | 'DROP TABLE public.foo;' 83 | ); 84 | new_script 85 | -------- 86 | 1 87 | 88 | This creates a new script with revision `1`. The function 89 | `metagration.new_script(up[, down])` expands the up and down code into 90 | dynamically created plpgsql functions. Once the script is created, it 91 | can then be run with `metagration.run()` 92 | 93 | # CALL metagration.run(); 94 | # \dt 95 | List of relations 96 | Schema | Name | Type | Owner 97 | --------+------+-------+---------- 98 | public | foo | table | postgres 99 | 100 | Now add another script with an unfortunate table name to be reverted: 101 | 102 | # SELECT metagration.new_script( 103 | 'CREATE TABLE public.bad (id bigserial);', 104 | 'DROP TABLE public.bad; 105 | ); 106 | new_script 107 | -------- 108 | 2 109 | # CALL metagration.run(); 110 | # \dt 111 | List of relations 112 | Schema | Name | Type | Owner 113 | --------+------+-------+---------- 114 | public | foo | table | postgres 115 | public | bad | table | postgres 116 | 117 | Now revision `2` can be reverted by calling `metagration.run()` with a 118 | specific target revision, in this case back to 1, and the `bad` table 119 | gets dropped: 120 | 121 | postgres=# CALL metagration.run(1); 122 | # \dt 123 | List of relations 124 | Schema | Name | Type | Owner 125 | --------+------+-------+---------- 126 | public | foo | table | postgres 127 | 128 | The current, previous, and next revisions can be queried: 129 | 130 | # SELECT metagration.previous_revision(); 131 | previous_revision 132 | ------------------ 133 | 0 134 | # SELECT metagration.current_revision(); 135 | current_revision 136 | ----------------- 137 | 1 138 | # SELECT metagration.next_revision(); 139 | next_revision 140 | -------------- 141 | 2 142 | 143 | Metagrations can also be run with a relative revision parameter passed 144 | as a text string: 145 | 146 | CALL metagration.run('1'); -- go forward one revision 147 | CALL metagration.run('-3'); -- go back three revisions 148 | 149 | A log of all migrations, their start and end revisions, times, and 150 | restore points are stored in the `metagration.log` table: 151 | 152 | # SELECT * FROM metagration.log ORDER BY migration_start; 153 | revision_start | revision_end | migration_start | migration_end | txid | restore_point | restore_point_lsn 154 | ----------------+--------------+-------------------------------+-------------------------------+------+-----------------------------------+------------------- 155 | 0 | 1 | 2020-05-13 23:13:02.830335+00 | 2020-05-13 23:13:02.831964+00 | 505 | 0|1|2020-05-13|23:13:02.830335+00 | 0/183F408 156 | 1 | 3 | 2020-05-13 23:13:02.841926+00 | 2020-05-13 23:13:02.8432+00 | 505 | 1|3|2020-05-13|23:13:02.841926+00 | 0/1841A20 157 | 3 | 4 | 2020-05-13 23:13:02.846628+00 | 2020-05-13 23:13:02.847429+00 | 505 | 3|4|2020-05-13|23:13:02.846628+00 | 0/1844730 158 | 4 | 1 | 2020-05-13 23:13:02.848043+00 | 2020-05-13 23:13:02.850642+00 | 505 | 4|1|2020-05-13|23:13:02.848043+00 | 0/18459C0 159 | 1 | 4 | 2020-05-13 23:13:02.852157+00 | 2020-05-13 23:13:02.858205+00 | 505 | 1|4|2020-05-13|23:13:02.852157+00 | 0/1846790 160 | 161 | Before each metagration a recovery restore point is created with 162 | [`pg_create_restore_point`](https://www.postgresql.org/docs/current/functions-admin.html#FUNCTIONS-ADMIN-BACKUP) 163 | and can be used for Point In Time Recovery to the point just before 164 | the migration and other recovery tasks. The current transaction id is 165 | also saved. 166 | 167 | ## Dynamic Metagrations 168 | 169 | Metagration scripts are stored procedures, and can be fully dynamic in 170 | terms of the SQL they execute when run. To facilitate this, the 171 | `run()` function accepts an optional `args jsonb` argument that is 172 | passed to each script when run. This allows scripts to respond to 173 | dynamic variables at run time. 174 | 175 | For plpgsql scripts built with `new_script`, optional local variable 176 | declarations can also be provided, in the following example, the index 177 | variable `i` in the `FOR` loops are declared in the `up_declare` and 178 | `down_declare` parameters to `new_script()` shown here: 179 | 180 | SELECT new_script( 181 | $up$ 182 | FOR i IN (SELECT * FROM generate_series(1, (args->>'target')::bigint, 1)) LOOP 183 | EXECUTE format('CREATE TABLE %I (id serial)', 'foo_' || i); 184 | END LOOP; 185 | $up$, 186 | $down$ 187 | FOR i IN (SELECT * FROM generate_series(1, (args->>'target')::bigint, 1)) LOOP 188 | EXECUTE format('DROP TABLE %I', 'foo_' || i); 189 | END LOOP; 190 | $down$, 191 | up_declare:='i bigint', 192 | down_declare:='i bigint' 193 | ); 194 | 195 | To run, pass an integer value for the `target` jsonb key in `args`: 196 | 197 | # CALL metagration.run(args:=jsonb_build_object('target', 3)); 198 | # \dt+ 199 | List of relations 200 | Schema | Name | Type | Owner | Size | Description 201 | --------+-------+-------+----------+---------+------------- 202 | public | foo_1 | table | postgres | 0 bytes | 203 | public | foo_2 | table | postgres | 0 bytes | 204 | public | foo_3 | table | postgres | 0 bytes | 205 | 206 | If your up script depends on `args`, it's likely your down scripts do 207 | too. Pass them as well to revert or, get the args used in the up 208 | migration from the `migration.log` table where they are saved. 209 | 210 | # CALL metagration.run('-1', args:=jsonb_build_object('target', 3)); 211 | # \dt+ 212 | List of relations 213 | Schema | Name | Type | Owner | Size | Description 214 | --------+---------+-------+----------+---------+------------- 215 | 216 | # SELECT migration_args FROM metagration.log 217 | WHERE revision_end = metagration.current_revision() 218 | ORDER BY migration_end DESC LIMIT 1; 219 | 220 | migration_args 221 | ---------------- 222 | {"target": 3} 223 | (1 row) 224 | 225 | ## Import and Exporting 226 | 227 | The obvious question is, if metagrations are stored procedures that 228 | makes DDL changes, who CREATEs the metagrations? They can be created 229 | programatically as shown above with `new_script` or by inserting 230 | directly into the `metagraiton.script` table. They can be imported and 231 | exported using any PostgreSQL client or admin tool. Because 232 | metagrations are in-database, they are dumped and restored when the 233 | database is backed up. 234 | 235 | You can still check your metagrations into source control and stream 236 | them into a new database when you initialize it, then call 237 | `metagrate.run()`. 238 | 239 | Since this process of creating metagrations is *decoupled* from the 240 | actual act of migration, it can be done using any of the many database 241 | management tools for PostgreSQL. Because metagration scripts are 242 | stored procedures, they are stateless database objects that can be 243 | exported, imported, dropped and re-created as necessary. 244 | 245 | A helpful tool for doing this `metagration.export()`. The `export()` 246 | function will generate SQL script file that `CREATE OR REPLACE`s the 247 | migration scripts and optionally clear and run them. Simply capture 248 | the output of this function, for example with: 249 | 250 | psql -A -t -U postgres -c 'select metagration.export()' > export_file.sql 251 | 252 | And then check it in to your source control. The scripts can then be 253 | imported with 254 | [`psql`](https://www.postgresql.org/docs/current/app-psql.html) or any 255 | other PostgreSQL client: 256 | 257 | psql < export_file.sql 258 | 259 | This will import all the migrations but not *run* them, for that you 260 | still call `metagration.run()` or pass `run_migrations:=true` as shown 261 | below. 262 | 263 | If `metagration.export(replace_scripts:=true)` is called the generated 264 | script will truncate the `script` and `log` tables and re-insert all 265 | the exported scripts. 266 | 267 | If `metagration.export(transactional:=true)` the generated script will 268 | wrap itself in `BEGIN/COMMIT`. 269 | 270 | If `metagration.export(run_migrations:=true)` the generated script 271 | will run the migrations immediately after inserting them. 272 | 273 | ## Docker Entrypoint 274 | 275 | Metagrations can be used easily from the standard postgres docker 276 | container entry point directory. The SQL code dumped from 277 | `export(run_migrations:=true)` (see above) can be dropped into the 278 | `/docker-entrypoint-initdb.d/` directory in the container and the 279 | migrations will be inserted and automatically run when the new 280 | container is initialized. 281 | 282 | ## How does it work? 283 | 284 | Metagration scripts are stored procedures run *in revision order*. 285 | This means that revision 2 is always run after 1, and before 3 when 286 | migrating forward, and the opposite when going backwards. It is not 287 | possible to insert "in between" two existing revisions, even if their 288 | revisions are not consecutive. A `BEFORE INSERT` trigger enforces 289 | that new scripts must have a `revision > max(revision)` for all 290 | existing scripts. While you can disable this trigger to bulk import 291 | revisions you will be responsible for their revision order being 292 | correct. 293 | 294 | When a script is created with `metagration.new_script()` the up and down 295 | code are substituted into the body dynamically generated plpgsql 296 | procedure. You don't have to use `new_script()`, a script can be written 297 | in any supported language that can write stored procedures, such as 298 | python and javascript. 299 | 300 | One and only one script at a time can be `is_current = true`. This is 301 | enforced with a `UNIQUE` partial index. The procedure 302 | `metagration.run()` also does a 'LOCK ... SHARE MODE' on the script 303 | table when it runs ensuring only one metagration script can run at a 304 | time. 305 | -------------------------------------------------------------------------------- /latest-changes.md: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- /metagration.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/michelp/metagration/a300a523ba6daad46c030cdce42afd0945687166/metagration.png -------------------------------------------------------------------------------- /metagration.svg: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /sql/metagration.sql: -------------------------------------------------------------------------------- 1 | DROP SCHEMA IF EXISTS metagration CASCADE; 2 | CREATE SCHEMA metagration; 3 | CREATE SCHEMA IF NOT EXISTS metagration_scripts; 4 | 5 | CREATE TABLE metagration.script ( 6 | revision bigserial PRIMARY KEY, 7 | is_current boolean DEFAULT false, 8 | script_schema text NOT null DEFAULT 'metagration_scripts', 9 | up_script text, 10 | down_script text, 11 | test_script text, 12 | args jsonb, 13 | comment text 14 | ); 15 | 16 | COMMENT ON TABLE metagration.script IS 17 | 'Table for metagration scripts.'; 18 | 19 | CREATE UNIQUE INDEX ON metagration.script (is_current) 20 | WHERE is_current = true; 21 | 22 | CREATE OR REPLACE FUNCTION metagration.check_script_trigger() 23 | RETURNS TRIGGER LANGUAGE plpgsql AS $$ 24 | DECLARE 25 | max_revision bigint; 26 | BEGIN 27 | SELECT max(revision) INTO max_revision FROM metagration.script; 28 | IF new.revision <= max_revision THEN 29 | RAISE 'Cannot insert script with revision <= %', max_revision; 30 | END IF; 31 | RETURN new; 32 | END; 33 | $$; 34 | 35 | CREATE TRIGGER before_insert_script_trigger 36 | BEFORE INSERT ON metagration.script 37 | FOR EACH ROW EXECUTE PROCEDURE metagration.check_script_trigger(); 38 | 39 | -- 0 is the "base" revision, which means no scripts applied. 40 | INSERT INTO metagration.script (revision, is_current) VALUES (0, true); 41 | 42 | CREATE TABLE metagration.log ( 43 | revision_start bigint REFERENCES metagration.script (revision), 44 | revision_end bigint REFERENCES metagration.script (revision), 45 | migration_start timestamptz not null, 46 | migration_end timestamptz, 47 | migration_args jsonb, 48 | txid bigint, 49 | restore_point text, 50 | restore_point_lsn pg_lsn, 51 | PRIMARY KEY (revision_start, revision_end, migration_start) 52 | ); 53 | 54 | COMMENT ON TABLE metagration.script IS 55 | 'Log of metagrations that have been applied, when and their restore points.'; 56 | 57 | CREATE OR REPLACE FUNCTION metagration.current_revision() 58 | RETURNS bigint LANGUAGE sql AS $$ 59 | SELECT revision FROM metagration.script WHERE is_current; 60 | $$; 61 | 62 | COMMENT ON FUNCTION metagration.current_revision() IS 63 | 'Returns the current revision or null if no revisions applied.'; 64 | 65 | CREATE OR REPLACE FUNCTION metagration.previous_revision(from_revision bigint=null) 66 | RETURNS bigint LANGUAGE sql AS $$ 67 | SELECT revision FROM metagration.script 68 | WHERE revision < coalesce(from_revision, metagration.current_revision()) 69 | ORDER BY revision DESC 70 | LIMIT 1; 71 | $$; 72 | 73 | COMMENT ON FUNCTION metagration.previous_revision(bigint) IS 74 | 'Returns the previons revision or null if no previous revision to the 75 | one supplied. If no revision is supplied, default to the current 76 | revision'; 77 | 78 | CREATE OR REPLACE FUNCTION metagration.next_revision(from_revision bigint=null) 79 | RETURNS bigint LANGUAGE sql AS $$ 80 | SELECT revision FROM metagration.script 81 | WHERE revision > coalesce(from_revision, metagration.current_revision()) 82 | ORDER BY revision ASC 83 | LIMIT 1; 84 | $$; 85 | 86 | COMMENT ON FUNCTION metagration.next_revision(bigint) IS 87 | 'Returns the next revision or null if no next revision to the 88 | one supplied. If no revision is supplied, default to the current 89 | revision'; 90 | 91 | CREATE OR REPLACE PROCEDURE metagration.run_up( 92 | revision_start bigint, 93 | revision_end bigint, 94 | args jsonb='{}', 95 | verify boolean=true) 96 | LANGUAGE plpgsql AS $$ 97 | DECLARE 98 | current_script metagration.script; 99 | BEGIN 100 | FOR current_script IN 101 | SELECT * FROM metagration.script 102 | WHERE revision > revision_start 103 | AND revision <= revision_end 104 | ORDER BY revision ASC 105 | LOOP 106 | EXECUTE format( 107 | 'CALL %I.%I($1)', 108 | current_script.script_schema, 109 | current_script.up_script) 110 | USING current_script.args || args; 111 | 112 | IF verify AND current_script.test_script IS NOT null THEN 113 | COMMIT; 114 | EXECUTE format( 115 | 'CALL %I.%I($1)', 116 | current_script.script_schema, 117 | current_script.test_script) 118 | USING current_script.args || args; 119 | ROLLBACK; 120 | END IF; 121 | UPDATE metagration.script 122 | SET is_current = false WHERE is_current; 123 | UPDATE metagration.script 124 | SET is_current = true 125 | WHERE revision = current_script.revision; 126 | END LOOP; 127 | END; 128 | $$; 129 | 130 | COMMENT ON PROCEDURE metagration.run_up(bigint, bigint, jsonb, boolean) IS 131 | 'Apply up scripts from start to end revisions.'; 132 | 133 | CREATE OR REPLACE PROCEDURE metagration.run_down( 134 | revision_start bigint, 135 | revision_end bigint, 136 | args jsonb='{}') 137 | LANGUAGE plpgsql AS $$ 138 | DECLARE 139 | current_script metagration.script; 140 | BEGIN 141 | FOR current_script IN 142 | SELECT * FROM metagration.script 143 | WHERE revision <= revision_start 144 | AND revision > revision_end 145 | ORDER BY revision DESC 146 | LOOP 147 | IF current_script.down_script IS null THEN 148 | RAISE 'No down script for revision %', current_script.revision; 149 | END IF; 150 | EXECUTE format('CALL %I.%I($1)', 151 | current_script.script_schema, 152 | current_script.down_script) 153 | USING current_script.args || args; 154 | UPDATE metagration.script 155 | SET is_current = false 156 | WHERE is_current; 157 | UPDATE metagration.script 158 | SET is_current = true 159 | WHERE 160 | revision = metagration.previous_revision(current_script.revision); 161 | END LOOP; 162 | END; 163 | $$; 164 | 165 | COMMENT ON PROCEDURE metagration.run_down(bigint, bigint, jsonb) IS 166 | 'Apply down scripts from start to end revisions.'; 167 | 168 | CREATE OR REPLACE PROCEDURE metagration.run(run_to bigint=null, args jsonb='{}', verify boolean=true) 169 | LANGUAGE plpgsql AS $$ 170 | DECLARE 171 | current_revision bigint; 172 | revision_start bigint; 173 | revision_end bigint; 174 | clock_now timestamptz; 175 | restore_point text; 176 | restore_point_lsn pg_lsn; 177 | BEGIN 178 | LOCK TABLE metagration.script IN SHARE MODE; 179 | current_revision = metagration.current_revision(); 180 | IF run_to = 0 THEN 181 | IF current_revision is null THEN 182 | RAISE 'No starting revision available.'; 183 | END IF; 184 | CALL metagration.run_down(current_revision, 0, args); 185 | RETURN; 186 | END IF; 187 | IF run_to IS null THEN 188 | SELECT max(revision) INTO run_to FROM metagration.script; 189 | END IF; 190 | SELECT revision INTO revision_end 191 | FROM metagration.script 192 | WHERE revision = run_to; 193 | IF revision_end IS null THEN 194 | RAISE 'no revision %', run_to; 195 | END IF; 196 | SELECT revision INTO revision_start 197 | FROM metagration.script 198 | WHERE is_current; 199 | IF revision_start IS null THEN 200 | revision_start = 0; 201 | END IF; 202 | IF revision_start = revision_end THEN 203 | RAISE '% is already the current revision', run_to; 204 | END IF; 205 | SELECT clock_timestamp() INTO clock_now; 206 | restore_point = format('%s|%s|%s', 207 | revision_start, 208 | revision_end, 209 | replace(clock_now::text, ' ', '|')); 210 | SELECT pg_create_restore_point(restore_point) INTO restore_point_lsn; 211 | IF revision_start < revision_end THEN 212 | CALL metagration.run_up(revision_start, revision_end, args, verify=verify); 213 | ELSE 214 | CALL metagration.run_down(revision_start, revision_end, args); 215 | END IF; 216 | INSERT INTO metagration.log ( 217 | revision_start, 218 | revision_end, 219 | migration_start, 220 | migration_end, 221 | migration_args, 222 | txid, 223 | restore_point, 224 | restore_point_lsn) 225 | VALUES ( 226 | revision_start, 227 | revision_end, 228 | clock_now, 229 | clock_timestamp(), 230 | args, 231 | txid_current(), 232 | restore_point, 233 | restore_point_lsn); 234 | END; 235 | $$; 236 | 237 | COMMENT ON PROCEDURE metagration.run(bigint, jsonb, boolean) IS 238 | 'Run from thecurrent revision, forwards or backwards to the target 239 | revision.'; 240 | 241 | CREATE OR REPLACE PROCEDURE metagration.run(run_to text, args jsonb='{}', verify boolean=true) 242 | LANGUAGE plpgsql AS $$ 243 | DECLARE 244 | revision_start bigint; 245 | revision_end bigint; 246 | delta bigint = run_to::bigint; 247 | BEGIN 248 | revision_start = metagration.current_revision(); 249 | EXECUTE format($f$ 250 | SELECT revision 251 | FROM metagration.script 252 | WHERE 253 | CASE WHEN $1 < 0 THEN 254 | revision < $2 255 | ELSE 256 | revision > $2 257 | END 258 | ORDER BY revision %s LIMIT 1 OFFSET %s 259 | $f$, 260 | CASE WHEN delta < 0 THEN 'desc' ELSE 'asc' END, 261 | abs(delta)-1) 262 | INTO revision_end 263 | USING delta, revision_start; 264 | IF revision_end IS null THEN 265 | RAISE 'No revision % away', run_to; 266 | END IF; 267 | CALL metagration.run(revision_end, args, verify=verify); 268 | END; 269 | $$; 270 | 271 | COMMENT ON PROCEDURE metagration.run(text, jsonb, boolean) IS 272 | 'Run from the current revision, forwards or backwards to the target 273 | revision using relative notation -1 to go back one, +3 to go forward 274 | 3, etc...'; 275 | 276 | CREATE OR REPLACE PROCEDURE metagration.assert(result text) 277 | LANGUAGE plpgsql AS $$ 278 | BEGIN 279 | ASSERT starts_with(result, 'ok'); 280 | RAISE NOTICE '%', result; 281 | END; 282 | $$; 283 | 284 | CREATE OR REPLACE PROCEDURE metagration.verify() 285 | LANGUAGE plpgsql AS $$ 286 | DECLARE 287 | current_script metagration.script; 288 | BEGIN 289 | FOR current_script IN 290 | SELECT * FROM metagration.script 291 | ORDER BY revision ASC 292 | LOOP 293 | IF current_script.test_script IS NOT null THEN 294 | EXECUTE format( 295 | 'CALL %I.%I($1)', 296 | current_script.script_schema, 297 | current_script.test_script) 298 | USING current_script.args; 299 | END IF; 300 | END LOOP; 301 | END; 302 | $$; 303 | 304 | COMMENT ON PROCEDURE metagration.verify() IS 305 | 'Verify all revisions.'; 306 | 307 | CREATE OR REPLACE FUNCTION metagration._proc_body(script_declare text, script text) 308 | RETURNS text LANGUAGE plpgsql AS $$ 309 | DECLARE 310 | buffer text = ''; 311 | BEGIN 312 | IF script_declare IS NOT null THEN 313 | buffer = buffer || format($f$ 314 | DECLARE 315 | %s; 316 | $f$, script_declare); 317 | END IF; 318 | 319 | buffer = buffer || format($f$ 320 | BEGIN 321 | %s 322 | RETURN; 323 | END;$f$, script); 324 | RETURN buffer; 325 | END;$$; 326 | 327 | CREATE OR REPLACE FUNCTION metagration._build_proc( 328 | use_schema text, 329 | script_name text, 330 | script_body text) 331 | RETURNS text LANGUAGE plpgsql AS $$ 332 | BEGIN 333 | RETURN format( 334 | $f$ 335 | CREATE OR REPLACE PROCEDURE %I.%I 336 | (args jsonb='{}') LANGUAGE plpgsql AS $%s$ 337 | %s 338 | $%s$; 339 | $f$, use_schema, script_name, script_name, script_body, script_name); 340 | END; 341 | $$; 342 | 343 | CREATE OR REPLACE FUNCTION metagration.new_script( 344 | up_script text, 345 | down_script text=null, 346 | test_script text=null, 347 | up_declare text=null, 348 | down_declare text=null, 349 | test_declare text=null, 350 | args jsonb='{}', 351 | use_schema text='metagration_scripts', 352 | comment text=null) 353 | RETURNS bigint 354 | LANGUAGE plpgsql AS $$ 355 | DECLARE 356 | this metagration.script; 357 | up_name text; 358 | down_name text = null; 359 | test_name text = null; 360 | BEGIN 361 | INSERT INTO metagration.script 362 | (args, script_schema, comment) 363 | VALUES 364 | (args, use_schema, comment) 365 | RETURNING * INTO this; 366 | up_name = '_' || this.revision || '_' || 'up'; 367 | if down_script IS NOT null THEN 368 | down_name = '_' || this.revision || '_' || 'down'; 369 | EXECUTE metagration._build_proc( 370 | use_schema, 371 | down_name, 372 | metagration._proc_body(down_declare, down_script)); 373 | END IF; 374 | if test_script IS NOT null THEN 375 | test_name = '_' || this.revision || '_' || 'test'; 376 | EXECUTE metagration._build_proc( 377 | use_schema, 378 | test_name, 379 | metagration._proc_body(test_declare, test_script)); 380 | END IF; 381 | EXECUTE metagration._build_proc( 382 | use_schema, 383 | up_name, 384 | metagration._proc_body(up_declare, up_script)); 385 | UPDATE metagration.script 386 | SET up_script = up_name, 387 | down_script = down_name, 388 | test_script = test_name 389 | WHERE revision = this.revision; 390 | RETURN this.revision; 391 | END; 392 | $$; 393 | 394 | CREATE OR REPLACE FUNCTION metagration._get_sourcedef( 395 | proc_schema text, proc_name text) 396 | RETURNS text LANGUAGE sql AS $$ 397 | SELECT pg_get_functiondef(p.oid) || ';' 398 | FROM pg_proc p, pg_namespace n 399 | WHERE p.pronamespace = n.oid 400 | AND p.proname=proc_name 401 | AND n.nspname=proc_schema; 402 | $$; 403 | 404 | CREATE OR REPLACE FUNCTION metagration.export( 405 | replace_scripts boolean=false, 406 | transactional boolean=false, 407 | run_migrations boolean=false) 408 | RETURNS text 409 | LANGUAGE plpgsql AS $$ 410 | DECLARE 411 | current_script metagration.script; 412 | buffer text=''; 413 | proc_source text; 414 | proc_language text; 415 | BEGIN 416 | IF transactional THEN 417 | buffer = buffer || ' 418 | BEGIN;'; 419 | END IF; 420 | IF replace_scripts THEN 421 | buffer = buffer || format( 422 | $f$ 423 | TRUNCATE metagration.script CASCADE; 424 | INSERT INTO metagration.script (revision, is_current) VALUES (0, true); 425 | $f$); 426 | END IF; 427 | FOR current_script IN 428 | SELECT * FROM metagration.script 429 | WHERE revision > 0 430 | ORDER BY revision 431 | LOOP 432 | buffer = buffer || metagration._get_sourcedef( 433 | current_script.script_schema, 434 | current_script.up_script); 435 | 436 | IF current_script.down_script IS NOT null THEN 437 | buffer = buffer || metagration._get_sourcedef( 438 | current_script.script_schema, 439 | current_script.down_script); 440 | END IF; 441 | IF replace_scripts THEN 442 | buffer = buffer || format( 443 | $f$ 444 | INSERT INTO metagration.script 445 | (revision, script_schema, up_script, down_script, args, comment) 446 | VALUES (%L, %L, %L, %L, %L, %L); 447 | $f$, 448 | current_script.revision, 449 | current_script.script_schema, 450 | current_script.up_script, 451 | current_script.down_script, 452 | current_script.args, 453 | current_script.comment); 454 | END IF; 455 | END LOOP; 456 | IF run_migrations THEN 457 | buffer = buffer || ' 458 | CALL metagration.run();'; 459 | END IF; 460 | IF transactional THEN 461 | buffer = buffer || ' 462 | COMMIT;'; 463 | END IF; 464 | RETURN buffer; 465 | END; 466 | $$; 467 | 468 | COMMENT ON FUNCTION metagration.export(boolean, boolean, boolean) IS 469 | 'Export metagration scripts as SQL file that can be loaded into fresh 470 | database. '; 471 | -------------------------------------------------------------------------------- /test.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | DB_HOST="metagration-test-db" 4 | DB_NAME="postgres" 5 | SU="postgres" 6 | EXEC="docker exec $DB_HOST" 7 | 8 | echo destroying test container and image 9 | docker rm --force "$DB_HOST" 10 | 11 | set -e 12 | 13 | echo building test image 14 | docker build . -t metagration/test 15 | 16 | echo running test container 17 | docker run -e POSTGRES_HOST_AUTH_METHOD=trust -d \ 18 | -v `pwd`:/metagration \ 19 | --name "$DB_HOST" \ 20 | metagration/test # \ 21 | # -c 'wal_level=logical' \ 22 | # -c 'archive_mode=on' \ 23 | # -c "archive_command='test ! -f /archivedir/%f && cp %p /archivedir/%f'" 24 | 25 | echo waiting for database to accept connections 26 | until 27 | $EXEC \ 28 | psql -o /dev/null -t -q -U "$SU" \ 29 | -c 'select pg_sleep(1)' \ 30 | 2>/dev/null; 31 | do sleep 1; 32 | done 33 | 34 | echo running tests 35 | $EXEC psql -U "$SU" -f /metagration/test/test.sql 36 | 37 | # docker rmi metagration/test 38 | -------------------------------------------------------------------------------- /test/core.sql: -------------------------------------------------------------------------------- 1 | SELECT lives_ok($$ 2 | SELECT new_script( 3 | 'CREATE TABLE foo (bar int);', 4 | 'DROP TABLE foo;'); 5 | $$, 'CREATE foo script'); 6 | 7 | CALL run(); 8 | 9 | SELECT current_revision() AS checkpoint \gset 10 | SELECT is(:checkpoint, 1, 'checkpoint is first'); 11 | 12 | SELECT has_table('foo'::name, 'floo exists'); 13 | 14 | SELECT lives_ok($$ 15 | SELECT new_script( 16 | 'CREATE TABLE lii (bar int);', 17 | 'DROP TABLE lii;'); 18 | $$, 'CREATE lii script'); 19 | 20 | SELECT lives_ok($$ 21 | SELECT new_script( 22 | 'CREATE TABLE loo (bar int);', 23 | 'DROP TABLE loo;'); 24 | $$, 'CREATE loo script'); 25 | 26 | CALL run(); 27 | 28 | -- SELECT * from log order by migration_start; 29 | 30 | SELECT is(previous_revision(), 2::bigint, 'previous revision is ' || previous_revision()); 31 | SELECT is(current_revision(), 3::bigint, 'current revision is ' || current_revision()); 32 | SELECT is(next_revision(), null, 'next revision is null'); 33 | 34 | SELECT has_table('lii'::name, 'lii exists'); 35 | SELECT has_table('loo'::name, 'loo exists'); 36 | 37 | SELECT lives_ok($$ 38 | SELECT new_script( 39 | 'CREATE TABLE zink (bar int);', 40 | 'DROP TABLE zink cascade;'); 41 | $$, 'CREATE zink script'); 42 | 43 | CALL run(); 44 | -- SELECT * from log order by migration_start; 45 | 46 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 47 | SELECT is(current_revision(), 4::bigint, 'current revision is ' || current_revision()); 48 | SELECT is(next_revision(), null, 'next revision is null'); 49 | 50 | CALL run(:checkpoint); 51 | 52 | SELECT is(previous_revision(), 0::bigint, 'previous revision is ' || previous_revision()); 53 | SELECT is(current_revision(), 1::bigint, 'current revision is ' || current_revision()); 54 | SELECT is(next_revision(), 2::bigint, 'next revision is ' || next_revision()); 55 | 56 | SELECT hasnt_table('zink'::name, 'no zink'); 57 | 58 | CALL run(); 59 | 60 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 61 | SELECT is(current_revision(), 4::bigint, 'current revision is ' || current_revision()); 62 | SELECT is(next_revision(), null, 'next revision is null'); 63 | 64 | SELECT has_table('zink'::name, 'zink exists'); 65 | 66 | CALL run(0); 67 | 68 | SELECT is(previous_revision(), null, 'previous revision is null'); 69 | SELECT is(current_revision(), 0::bigint, 'current revision is ' || current_revision()); 70 | SELECT is(next_revision(), 1::bigint, 'next revision is ' || next_revision()); 71 | 72 | SELECT hasnt_table('zink'::name, 'no zink'); 73 | SELECT hasnt_table('lii'::name, 'no lii'); 74 | SELECT hasnt_table('loo'::name, 'no loo'); 75 | 76 | CALL run(); 77 | 78 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 79 | SELECT is(current_revision(), 4::bigint, 'current revision is ' || current_revision()); 80 | SELECT is(next_revision(), null, 'next revision is null'); 81 | 82 | SELECT has_table('zink'::name, 'zink exists'); 83 | SELECT has_table('lii'::name, 'lii exists'); 84 | SELECT has_table('loo'::name, 'loo exists'); 85 | 86 | -- SELECT * from log order by migration_start order by migration_start; 87 | 88 | \o _tmp_test_migration_export.sql 89 | SELECT export(); 90 | \o 91 | \i _tmp_test_migration_export.sql 92 | \! rm _tmp_test_migration_export.sql 93 | 94 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 95 | SELECT is(current_revision(), 4::bigint, 'current_revision is ' || current_revision()); 96 | SELECT is(next_revision(), null, 'next revision is null'); 97 | 98 | SELECT has_table('zink'::name, 'zink exists'); 99 | SELECT has_table('lii'::name, 'lii exists'); 100 | SELECT has_table('loo'::name, 'loo exists'); 101 | 102 | CALL run(0); 103 | 104 | SELECT is(previous_revision(), null, 'previous revision is null'); 105 | SELECT is(current_revision(), 0::bigint, 'current revision is ' || current_revision()); 106 | SELECT is(next_revision(), 1::bigint, 'next revision is ' || next_revision()); 107 | 108 | SELECT hasnt_table('zink'::name, 'no zink'); 109 | SELECT hasnt_table('lii'::name, 'no lii'); 110 | SELECT hasnt_table('loo'::name, 'no loo'); 111 | 112 | \o _tmp_test_migration_export_txn.sql 113 | SELECT export(transactional:=true); 114 | \o 115 | \i _tmp_test_migration_export_txn.sql 116 | \! rm _tmp_test_migration_export_txn.sql 117 | 118 | CALL run(); 119 | 120 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 121 | SELECT is(current_revision(), 4::bigint, 'current_revision is ' || current_revision()); 122 | SELECT is(next_revision(), null, 'next revision is null'); 123 | 124 | SELECT has_table('zink'::name, 'zink exists'); 125 | SELECT has_table('lii'::name, 'lii exists'); 126 | SELECT has_table('loo'::name, 'loo exists'); 127 | 128 | CALL run(0); 129 | 130 | SELECT is(previous_revision(), null, 'previous revision is null'); 131 | SELECT is(current_revision(), 0::bigint, 'current revision is ' || current_revision()); 132 | SELECT is(next_revision(), 1::bigint, 'next revision is ' || next_revision()); 133 | 134 | SELECT hasnt_table('zink'::name, 'no zink'); 135 | SELECT hasnt_table('lii'::name, 'no lii'); 136 | SELECT hasnt_table('loo'::name, 'no loo'); 137 | 138 | \o _tmp_test_migration_export_replace.sql 139 | SELECT export(replace_scripts:=true); 140 | \o 141 | \i _tmp_test_migration_export_replace.sql 142 | \! rm _tmp_test_migration_export_replace.sql 143 | 144 | SELECT is(previous_revision(), null, 'previous revision is null'); 145 | SELECT is(current_revision(), 0::bigint, 'current revision is ' || current_revision()); 146 | SELECT is(next_revision(), 1::bigint, 'next revision is ' || next_revision()); 147 | 148 | SELECT hasnt_table('zink'::name, 'no zink'); 149 | SELECT hasnt_table('lii'::name, 'no lii'); 150 | SELECT hasnt_table('loo'::name, 'no loo'); 151 | 152 | CALL run(); 153 | 154 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 155 | SELECT is(current_revision(), 4::bigint, 'current_revision is ' || current_revision()); 156 | SELECT is(next_revision(), null, 'next revision is null'); 157 | 158 | SELECT has_table('zink'::name, 'zink exists'); 159 | SELECT has_table('lii'::name, 'lii exists'); 160 | SELECT has_table('loo'::name, 'loo exists'); 161 | 162 | CALL run(0); 163 | 164 | SELECT is(previous_revision(), null, 'previous revision is null'); 165 | SELECT is(current_revision(), 0::bigint, 'current revision is ' || current_revision()); 166 | SELECT is(next_revision(), 1::bigint, 'next revision is ' || next_revision()); 167 | 168 | SELECT hasnt_table('zink'::name, 'no zink'); 169 | SELECT hasnt_table('lii'::name, 'no lii'); 170 | SELECT hasnt_table('loo'::name, 'no loo'); 171 | 172 | \o _tmp_test_migration_export_run.sql 173 | SELECT export(run_migrations:=true); 174 | \o 175 | \i _tmp_test_migration_export_run.sql 176 | \! rm _tmp_test_migration_export_run.sql 177 | 178 | SELECT is(previous_revision(), 3::bigint, 'previous revision is ' || previous_revision()); 179 | SELECT is(current_revision(), 4::bigint, 'current_revision is ' || current_revision()); 180 | SELECT is(next_revision(), null, 'next revision is null'); 181 | 182 | SELECT has_table('zink'::name, 'zink exists'); 183 | SELECT has_table('lii'::name, 'lii exists'); 184 | SELECT has_table('loo'::name, 'loo exists'); 185 | 186 | SELECT lives_ok($$ 187 | SELECT new_script( 188 | $up$ 189 | FOR i IN (SELECT * FROM generate_series(1, (args->>'target')::bigint, 1)) LOOP 190 | EXECUTE format('CREATE TABLE %I (id serial)', 'forks_' || i); 191 | END LOOP; 192 | $up$, 193 | $down$ 194 | FOR i IN (SELECT * FROM generate_series(1, (args->>'target')::bigint, 1)) LOOP 195 | EXECUTE format('DROP TABLE %I', 'forks_' || i); 196 | END LOOP; 197 | $down$, 198 | up_declare:='i bigint', 199 | down_declare:='i bigint', 200 | args:=jsonb_build_object('target', 3) 201 | ); 202 | $$, 'CREATE forks script'); 203 | 204 | CALL run(); 205 | 206 | SELECT has_table('forks_1'::name, 'forks_1 exists'); 207 | SELECT has_table('forks_2'::name, 'forks_2 exists'); 208 | SELECT has_table('forks_3'::name, 'forks_3 exists'); 209 | 210 | CALL run('-1'); 211 | 212 | SELECT hasnt_table('forks_1'::name, 'no forks_1'); 213 | SELECT hasnt_table('forks_2'::name, 'no forks_2'); 214 | SELECT hasnt_table('forks_3'::name, 'no forks_3'); 215 | 216 | CALL run('+1', args:=jsonb_build_object('target', 2)); 217 | 218 | SELECT has_table('forks_1'::name, 'forks_1 exists'); 219 | SELECT has_table('forks_2'::name, 'forks_2 exists'); 220 | SELECT hasnt_table('forks_3'::name, 'no forks_3'); 221 | 222 | CALL run('-1', args:=jsonb_build_object('target', 2)); 223 | 224 | SELECT hasnt_table('forks_1'::name, 'no forks_1'); 225 | SELECT hasnt_table('forks_2'::name, 'no forks_2'); 226 | SELECT hasnt_table('forks_3'::name, 'no forks_3'); 227 | 228 | SELECT * from log order by migration_start; 229 | -------------------------------------------------------------------------------- /test/test.sql: -------------------------------------------------------------------------------- 1 | \pset format unaligned 2 | \pset tuples_only true 3 | \pset pager 4 | 5 | -- \set ECHO none 6 | -- \set ON_ERROR_ROLLBACK 1 7 | -- \set ON_ERROR_STOP true 8 | -- \set QUIET 1 9 | 10 | CREATE EXTENSION pgtap; 11 | 12 | SET search_path = public, pgtap, metagration; 13 | 14 | SELECT plan(100); 15 | \ir core.sql 16 | \ir verify.sql 17 | SELECT * FROM finish(); 18 | -------------------------------------------------------------------------------- /test/verify.sql: -------------------------------------------------------------------------------- 1 | 2 | SELECT lives_ok($$ 3 | SELECT new_script( 4 | 'CREATE TABLE laa (bar int);', 5 | down_script:='DROP TABLE laa;', 6 | test_script:=$test$ 7 | CALL metagration.assert(has_table('laa'::name, 'Verify laa exists')); 8 | RAISE NOTICE 'hi this is the test script calling.'; 9 | $test$ 10 | ); 11 | $$, 'CREATE laa script with test'); 12 | 13 | -- Run script and verify 14 | 15 | CALL metagration.run(verify:=true); 16 | 17 | CALL metagration.verify(); -- no exception 18 | 19 | DROP TABLE laa; -- do something evil without a migration 20 | 21 | select throws_ok('CALL metagration.verify()'); 22 | --------------------------------------------------------------------------------