forked from tech-by-design/polyglot-prime
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
3 changed files
with
745 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,108 @@ | ||
|
||
# Information Schema Lifecycle Manager (ISLM) | ||
|
||
## Overview | ||
The Information Schema Lifecycle Manager (ISLM) is a PostgreSQL-native schema migration system designed to manage and automate database schema evolution. By encapsulating schema evolution (migration) logic within PostgreSQL stored routines, ISLM provides a robust and manageable approach to database schema evolution. It operates within a dedicated schema named `info_schema_lifecycle` and uses stateless helper functions (`islm_*`) to help DBAs orchestrate migrations based on naming conventions. | ||
|
||
## Significant Features | ||
- **Schema and Bootstrap Procedure**: | ||
- The `info_schema_lifecycle` schema contains all ISLM-related objects. | ||
- The `islm_bootstrap_idempotent` procedure creates essential tables: `islm_infrastructure_artifact` and `islm_governance`. | ||
- `islm_infrastructure_artifact` stores governance and infrastructure-related artifacts. | ||
- `islm_governance` manages schema migrations and their lifecycle, including details such as migration routine names, versions, reasons, idempotency, and SCXML states. | ||
|
||
- **Helper Functions**: | ||
- `migration_routine_candidate`: Finds migration routines based on naming conventions and returns relevant details, including possible undo and status routines. | ||
- `migration_routine_state`: Provides the migration status for each candidate routine by joining the results of `migration_routine_candidate` with the `islm_governance` table. | ||
|
||
- **Instruction and Script Generation**: | ||
- `islm_migration_instruction`: Discovers migration routines and generates instructions for their execution, based on the current state and idempotency. | ||
- `islm_migration_script`: Generates a SQL script for executing migration routines, based on the instructions from `islm_migration_instruction`. | ||
|
||
## Benefits | ||
- **Simplicity**: ISLM is simple and straightforward to use, operating entirely within PostgreSQL without the need for external tools. | ||
- **PostgreSQL-Native**: ISLM leverages PostgreSQL's native functionality, ensuring compatibility and ease of use within PostgreSQL environments. | ||
- **Focus on Documentation**: ISLM's design allows teams to focus on clear and thorough documentation of database schema evolution. | ||
|
||
## Analysis of Alternatives | ||
|
||
### Flyway | ||
- **Versioned Migrations**: Each migration has a version, a description, and a checksum. Migrations can be written in SQL or Java. | ||
- **Checksum Validation**: Flyway validates on startup that the migrations applied to the database match the ones available locally. | ||
- **Repair Functionality**: Provides a repair command to correct the schema history table if needed. | ||
- **Callbacks**: Custom operations can be performed before/after each migration, or before/after all migrations. | ||
- **Configuration Options**: Extensive configuration options available through files, environment variables, and command-line arguments. | ||
- **Cross-Team Development**: Supports working in a team environment with branching and merging. | ||
|
||
### Liquibase | ||
- **XML, YAML, JSON, and SQL Formats**: Changelog files can be written in various formats. | ||
- **Database-Agnostic Syntax**: Offers a database-agnostic syntax for changesets, which are translated into database-specific SQL. | ||
- **Changeset Execution**: Changesets can include preconditions, rollback code, and can be executed in transactions. | ||
- **Database Refactoring**: Manages a sequence of changes to the database schema, including complex refactoring. | ||
- **Command Line and Maven/Gradle Integration**: Offers command-line tools and integrates with Maven and Gradle. | ||
|
||
### ISLM | ||
- **Simplicity**: ISLM is simple and straightforward to use. Instead of creating an external strategy for PostgreSQL, ISLM does everything inside Postgres. | ||
|
||
### Summary | ||
- **Flyway**: Best for projects needing versioned migrations, checksum validation, and extensive configuration options, particularly in Java-based environments. | ||
- **Liquibase**: Ideal for projects requiring a database-agnostic approach, multiple changelog formats, and integration with build tools like Maven and Gradle. | ||
- **ISLM**: Best for teams looking for a straightforward solution that operates entirely within PostgreSQL without the need for external tools. | ||
|
||
## Usage | ||
To start using ISLM, follow these steps: | ||
|
||
### 1. Load the islm-prime.psql File | ||
Use the `psql` command-line tool to load the islm-prime.psql file into your PostgreSQL database: | ||
|
||
```sh | ||
psql -f islm-prime.psql | ||
``` | ||
|
||
### 2. Bootstrap ISLM | ||
Run the `islm_bootstrap_idempotent` procedure to create the necessary tables and objects: | ||
|
||
```sql | ||
CALL "info_schema_lifecycle"."islm_bootstrap_idempotent"(); | ||
``` | ||
|
||
### 3. Define Migration Routines | ||
Follow the naming conventions to define your migration routines. The expected naming conventions are: | ||
- `migrate_vYYYY_MM_DD_HH_MM_stateful_XYZ` | ||
- `migrate_vYYYY_MM_DD_HH_MM_idempotent_XYZ` | ||
|
||
### 4. Use Helper Functions to Manage Migrations | ||
By default, all helper functions use the `info_schema_lifecycle` schema and other default arguments. You can pass in other arguments as appropriate. | ||
|
||
#### Discover Migration Routines | ||
To find migration routines based on the naming conventions: | ||
|
||
```sql | ||
SELECT * FROM "info_schema_lifecycle"."migration_routine_candidate"(); | ||
``` | ||
|
||
#### Check Migration Status | ||
To get the migration status for each candidate routine: | ||
|
||
```sql | ||
SELECT * FROM "info_schema_lifecycle"."migration_routine_state"(); | ||
``` | ||
|
||
#### Generate Migration Instructions | ||
To discover migration routines and generate instructions for their execution: | ||
|
||
```sql | ||
SELECT * FROM "info_schema_lifecycle"."islm_migration_instruction"(); | ||
``` | ||
|
||
#### Generate Migration Script | ||
To generate a SQL script for executing migration routines: | ||
|
||
```sql | ||
SELECT "info_schema_lifecycle"."islm_migration_script"(); | ||
``` | ||
|
||
For detailed usage and examples, refer to the source code and comments within the islm-prime.psql file. | ||
|
||
## License | ||
This project is licensed under the MIT License - see the LICENSE file for details. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,220 @@ | ||
-- Drop and recreate the info_schema_lifecycle_assurance schema to ensure a clean environment | ||
DROP SCHEMA IF EXISTS info_schema_lifecycle_assurance CASCADE; | ||
CREATE SCHEMA info_schema_lifecycle_assurance; | ||
|
||
-- Create a custom testing function in the info_schema_lifecycle_assurance schema | ||
CREATE OR REPLACE FUNCTION info_schema_lifecycle_assurance.assert_equals(expected TEXT, actual TEXT, description TEXT) | ||
RETURNS void LANGUAGE plpgsql AS | ||
$$ | ||
BEGIN | ||
IF expected IS DISTINCT FROM actual THEN | ||
RAISE NOTICE '[FAIL] % - Expected: %, Actual: %', description, expected, actual; | ||
ELSE | ||
RAISE NOTICE '[pass] %', description; | ||
END IF; | ||
END; | ||
$$; | ||
|
||
-- Create the islm_test_structs procedure in the info_schema_lifecycle_assurance schema | ||
CREATE OR REPLACE PROCEDURE info_schema_lifecycle_assurance.islm_test_structs() | ||
LANGUAGE plpgsql AS | ||
$$ | ||
BEGIN | ||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.tables WHERE table_schema = 'info_schema_lifecycle' AND table_name = 'islm_infrastructure_artifact')::TEXT, | ||
'Table islm_infrastructure_artifact should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.tables WHERE table_schema = 'info_schema_lifecycle' AND table_name = 'islm_governance')::TEXT, | ||
'Table islm_governance should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle' AND routine_name = 'islm_bootstrap_idempotent')::TEXT, | ||
'Single non-overloaded function islm_bootstrap_idempotent should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle' AND routine_name = 'migration_routine_candidate')::TEXT, | ||
'Single non-overloaded function migration_routine_candidate should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle' AND routine_name = 'migration_routine_state')::TEXT, | ||
'Single non-overloaded function migration_routine_state should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle' AND routine_name = 'islm_migration_instruction')::TEXT, | ||
'Single non-overloaded function islm_migration_instruction should exist in info_schema_lifecycle schema' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle' AND routine_name = 'islm_migration_script')::TEXT, | ||
'Single non-overloaded function islm_migration_script should exist in info_schema_lifecycle schema' | ||
); | ||
END; | ||
$$; | ||
|
||
-- Create the islm_test_candidates procedure in the info_schema_lifecycle_assurance schema | ||
CREATE OR REPLACE PROCEDURE info_schema_lifecycle_assurance.islm_test_candidates() | ||
LANGUAGE plpgsql AS | ||
$$ | ||
BEGIN | ||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_00_stateful_example() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_00_stateful_example_undo() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_00_stateful_example_status() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_01_idempotent_example() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_01_idempotent_example_status() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
CREATE FUNCTION info_schema_lifecycle_assurance.migrate_v2024_07_14_12_02_stateful_example() | ||
RETURNS void LANGUAGE sql AS | ||
'SELECT 1'; | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'3', | ||
(SELECT COUNT(*)::TEXT FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance')), | ||
'migration_routine_candidate should return 3 candidates' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'2024_07_14_12_00', | ||
(SELECT migration_version FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_00_stateful_example'), | ||
'migration_routine_candidate should return correct version "2024_07_14_12_00" for migrate_v2024_07_14_12_00_stateful_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'false', | ||
(SELECT is_idempotent::TEXT FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_00_stateful_example'), | ||
'migration_routine_candidate should return correct idempotent status "false" for migrate_v2024_07_14_12_00_stateful_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'example', | ||
(SELECT migration_reason FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_00_stateful_example'), | ||
'migration_routine_candidate should return correct reason "example" for migrate_v2024_07_14_12_00_stateful_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'2024_07_14_12_01', | ||
(SELECT migration_version FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_01_idempotent_example'), | ||
'migration_routine_candidate should return correct version "2024_07_14_12_01" for migrate_v2024_07_14_12_01_idempotent_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'true', | ||
(SELECT is_idempotent::TEXT FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_01_idempotent_example'), | ||
'migration_routine_candidate should return correct idempotent status "true" for migrate_v2024_07_14_12_01_idempotent_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'example', | ||
(SELECT migration_reason FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_01_idempotent_example'), | ||
'migration_routine_candidate should return correct reason "example" for migrate_v2024_07_14_12_01_idempotent_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'2024_07_14_12_02', | ||
(SELECT migration_version FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_02_stateful_example'), | ||
'migration_routine_candidate should return correct version "2024_07_14_12_02" for migrate_v2024_07_14_12_02_stateful_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'false', | ||
(SELECT is_idempotent::TEXT FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_02_stateful_example'), | ||
'migration_routine_candidate should return correct idempotent status "false" for migrate_v2024_07_14_12_02_stateful_example' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'example', | ||
(SELECT migration_reason FROM info_schema_lifecycle.migration_routine_candidate('info_schema_lifecycle_assurance') WHERE migration_routine_name = 'migrate_v2024_07_14_12_02_stateful_example'), | ||
'migration_routine_candidate should return correct reason "example" for migrate_v2024_07_14_12_02_stateful_example' | ||
); | ||
|
||
-- Assert the existence of undo and status functions for migrate_v2024_07_14_12_00_stateful_example | ||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_00_stateful_example_undo')::TEXT, | ||
'Undo function for migrate_v2024_07_14_12_00_stateful_example should exist' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_00_stateful_example_status')::TEXT, | ||
'Status function for migrate_v2024_07_14_12_00_stateful_example should exist' | ||
); | ||
|
||
-- Assert the existence of status function for migrate_v2024_07_14_12_01_idempotent_example | ||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'0', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_01_idempotent_example_undo')::TEXT, | ||
'Undo function for migrate_v2024_07_14_12_01_idempotent_example should not exist' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'1', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_01_idempotent_example_status')::TEXT, | ||
'Status function for migrate_v2024_07_14_12_01_idempotent_example should exist' | ||
); | ||
|
||
-- Assert no undo or status functions for migrate_v2024_07_14_12_02_stateful_example | ||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'0', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_02_stateful_example_undo')::TEXT, | ||
'Undo function for migrate_v2024_07_14_12_02_stateful_example should not exist' | ||
); | ||
|
||
PERFORM info_schema_lifecycle_assurance.assert_equals( | ||
'0', | ||
(SELECT COUNT(*)::TEXT FROM information_schema.routines WHERE routine_schema = 'info_schema_lifecycle_assurance' AND routine_name = 'migrate_v2024_07_14_12_02_stateful_example_status')::TEXT, | ||
'Status function for migrate_v2024_07_14_12_02_stateful_example should not exist' | ||
); | ||
END; | ||
$$; | ||
|
||
-- Create the islm_test_prime procedure in the info_schema_lifecycle_assurance schema | ||
CREATE OR REPLACE PROCEDURE info_schema_lifecycle_assurance.islm_test_prime() | ||
LANGUAGE plpgsql AS | ||
$$ | ||
BEGIN | ||
-- Note: pgTAP does not support running in custom schemas, so we are using a custom test infrastructure. | ||
-- Additionally, pgTAP requires the public schema which we do not allow. | ||
|
||
CALL info_schema_lifecycle_assurance.islm_test_structs(); | ||
CALL info_schema_lifecycle_assurance.islm_test_candidates(); | ||
|
||
-- Additional tests can be added here in future | ||
END; | ||
$$; | ||
|
||
-- Note: pgTAP does not support running in custom schemas, so we are using a custom test infrastructure. | ||
|
||
-- Run the islm_test_prime procedure to ensure tables and functions exist using the custom test infrastructure | ||
DO | ||
$$ | ||
BEGIN | ||
CALL info_schema_lifecycle_assurance.islm_test_prime(); | ||
END; | ||
$$; |
Oops, something went wrong.