taler-rust

GNU Taler code in Rust. Largely core banking integrations.
Log | Files | Refs | Submodules | README | LICENSE

versioning.sql (11758B)


      1 -- LICENSE AND COPYRIGHT
      2 --
      3 -- Copyright (C) 2010 Hubert depesz Lubaczewski
      4 --
      5 -- This program is distributed under the (Revised) BSD License:
      6 -- L<http://www.opensource.org/licenses/bsd-license.php>
      7 --
      8 -- Redistribution and use in source and binary forms, with or without
      9 -- modification, are permitted provided that the following conditions
     10 -- are met:
     11 --
     12 -- * Redistributions of source code must retain the above copyright
     13 -- notice, this list of conditions and the following disclaimer.
     14 --
     15 -- * Redistributions in binary form must reproduce the above copyright
     16 --   notice, this list of conditions and the following disclaimer in the
     17 --   documentation and/or other materials provided with the distribution.
     18 --
     19 -- * Neither the name of Hubert depesz Lubaczewski's Organization
     20 --   nor the names of its contributors may be used to endorse or
     21 --   promote products derived from this software without specific
     22 --   prior written permission.
     23 --
     24 -- THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
     25 -- AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
     26 -- IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
     27 -- DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE
     28 -- FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
     29 -- DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR
     30 -- SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER
     31 -- CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY,
     32 -- OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
     33 -- OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
     34 --
     35 -- Code origin: https://gitlab.com/depesz/Versioning/blob/master/install.versioning.sql
     36 --
     37 --
     38 -- # NAME
     39 --
     40 -- **Versioning** - simplistic take on tracking and applying changes to databases.
     41 --
     42 -- # DESCRIPTION
     43 --
     44 -- This project strives to provide simple way to manage changes to
     45 -- database.
     46 --
     47 -- Instead of making changes on development server, then finding
     48 -- differences between production and development, deciding which ones
     49 -- should be installed on production, and finding a way to install them -
     50 -- you start with writing diffs themselves!
     51 --
     52 -- # INSTALLATION
     53 --
     54 -- To install versioning simply run install.versioning.sql in your database
     55 -- (all of them: production, stage, test, devel, ...).
     56 --
     57 -- # USAGE
     58 --
     59 -- In your files with patches to database, put whole logic in single
     60 -- transaction, and use \_v.\* functions - usually \_v.register_patch() at
     61 -- least to make sure everything is OK.
     62 --
     63 -- For example. Let's assume you have patch files:
     64 --
     65 -- ## 0001.sql:
     66 --
     67 -- ```
     68 -- create table users (id serial primary key, username text);
     69 -- ```
     70 --
     71 -- ## 0002.sql:
     72 --
     73 -- ```
     74 -- insert into users (username) values ('depesz');
     75 -- ```
     76 -- To change it to use versioning you would change the files, to this
     77 -- state:
     78 --
     79 -- 0000.sql:
     80 --
     81 -- ```
     82 -- BEGIN;
     83 -- select _v.register_patch('000-base', NULL, NULL);
     84 -- create table users (id serial primary key, username text);
     85 -- COMMIT;
     86 -- ```
     87 --
     88 -- ## 0002.sql:
     89 --
     90 -- ```
     91 -- BEGIN;
     92 -- select _v.register_patch('001-users', ARRAY['000-base'], NULL);
     93 -- insert into users (username) values ('depesz');
     94 -- COMMIT;
     95 -- ```
     96 --
     97 -- This will make sure that patch 001-users can only be applied after
     98 -- 000-base.
     99 --
    100 -- # AVAILABLE FUNCTIONS
    101 --
    102 -- ## \_v.register_patch( TEXT )
    103 --
    104 -- Registers named patch, or dies if it is already registered.
    105 --
    106 -- Returns integer which is id of patch in \_v.patches table - only if it
    107 -- succeeded.
    108 --
    109 -- ## \_v.register_patch( TEXT, TEXT[] )
    110 --
    111 -- Same as \_v.register_patch( TEXT ), but checks is all given patches (given as
    112 -- array in second argument) are already registered.
    113 --
    114 -- ## \_v.register_patch( TEXT, TEXT[], TEXT[] )
    115 --
    116 -- Same as \_v.register_patch( TEXT, TEXT[] ), but also checks if there are no conflicts with preexisting patches.
    117 --
    118 -- Third argument is array of names of patches that conflict with current one. So
    119 -- if any of them is installed - register_patch will error out.
    120 --
    121 -- ## \_v.unregister_patch( TEXT )
    122 --
    123 -- Removes information about given patch from the versioning data.
    124 --
    125 -- It doesn't remove objects that were created by this patch - just removes
    126 -- metainformation.
    127 --
    128 -- ## \_v.assert_user_is_superuser()
    129 --
    130 -- Make sure that current patch is being loaded by superuser.
    131 --
    132 -- If it's not - it will raise exception, and break transaction.
    133 --
    134 -- ## \_v.assert_user_is_not_superuser()
    135 --
    136 -- Make sure that current patch is not being loaded by superuser.
    137 --
    138 -- If it is - it will raise exception, and break transaction.
    139 --
    140 -- ## \_v.assert_user_is_one_of(TEXT, TEXT, ... )
    141 --
    142 -- Make sure that current patch is being loaded by one of listed users.
    143 --
    144 -- If ```current_user``` is not listed as one of arguments - function will raise
    145 -- exception and break the transaction.
    146 
    147 BEGIN;
    148 
    149 
    150 -- This file adds versioning support to database it will be loaded to.
    151 -- It requires that PL/pgSQL is already loaded - will raise exception otherwise.
    152 -- All versioning "stuff" (tables, functions) is in "_v" schema.
    153 
    154 -- All functions are defined as 'RETURNS SETOF INT4' to be able to make them to RETURN literally nothing (0 rows).
    155 -- >> RETURNS VOID<< IS similar, but it still outputs "empty line" in psql when calling
    156 CREATE SCHEMA IF NOT EXISTS _v;
    157 COMMENT ON SCHEMA _v IS 'Schema for versioning data and functionality.';
    158 
    159 CREATE TABLE IF NOT EXISTS _v.patches (
    160     patch_name  TEXT        PRIMARY KEY,
    161     applied_tsz TIMESTAMPTZ NOT NULL DEFAULT now(),
    162     applied_by  TEXT        NOT NULL,
    163     requires    TEXT[],
    164     conflicts   TEXT[]
    165 );
    166 COMMENT ON TABLE _v.patches              IS 'Contains information about what patches are currently applied on database.';
    167 COMMENT ON COLUMN _v.patches.patch_name  IS 'Name of patch, has to be unique for every patch.';
    168 COMMENT ON COLUMN _v.patches.applied_tsz IS 'When the patch was applied.';
    169 COMMENT ON COLUMN _v.patches.applied_by  IS 'Who applied this patch (PostgreSQL username)';
    170 COMMENT ON COLUMN _v.patches.requires    IS 'List of patches that are required for given patch.';
    171 COMMENT ON COLUMN _v.patches.conflicts   IS 'List of patches that conflict with given patch.';
    172 
    173 CREATE OR REPLACE FUNCTION _v.register_patch( IN in_patch_name TEXT, IN in_requirements TEXT[], in_conflicts TEXT[], OUT versioning INT4 ) RETURNS setof INT4 AS $$
    174 DECLARE
    175     t_text   TEXT;
    176     t_text_a TEXT[];
    177     i INT4;
    178 BEGIN
    179     -- Thanks to this we know only one patch will be applied at a time
    180     LOCK TABLE _v.patches IN EXCLUSIVE MODE;
    181 
    182     SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_patch_name;
    183     IF FOUND THEN
    184         RAISE EXCEPTION 'Patch % is already applied!', in_patch_name;
    185     END IF;
    186 
    187     t_text_a := ARRAY( SELECT patch_name FROM _v.patches WHERE patch_name = any( in_conflicts ) );
    188     IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
    189         RAISE EXCEPTION 'Versioning patches conflict. Conflicting patche(s) installed: %.', array_to_string( t_text_a, ', ' );
    190     END IF;
    191 
    192     IF array_upper( in_requirements, 1 ) IS NOT NULL THEN
    193         t_text_a := '{}';
    194         FOR i IN array_lower( in_requirements, 1 ) .. array_upper( in_requirements, 1 ) LOOP
    195             SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_requirements[i];
    196             IF NOT FOUND THEN
    197                 t_text_a := t_text_a || in_requirements[i];
    198             END IF;
    199         END LOOP;
    200         IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
    201             RAISE EXCEPTION 'Missing prerequisite(s): %.', array_to_string( t_text_a, ', ' );
    202         END IF;
    203     END IF;
    204 
    205     INSERT INTO _v.patches (patch_name, applied_tsz, applied_by, requires, conflicts ) VALUES ( in_patch_name, now(), current_user, coalesce( in_requirements, '{}' ), coalesce( in_conflicts, '{}' ) );
    206     RETURN;
    207 END;
    208 $$ language plpgsql;
    209 COMMENT ON FUNCTION _v.register_patch( TEXT, TEXT[], TEXT[] ) IS 'Function to register patches in database. Raises exception if there are conflicts, prerequisites are not installed or the migration has already been installed.';
    210 
    211 CREATE OR REPLACE FUNCTION _v.register_patch( TEXT, TEXT[] ) RETURNS setof INT4 AS $$
    212     SELECT _v.register_patch( $1, $2, NULL );
    213 $$ language sql;
    214 COMMENT ON FUNCTION _v.register_patch( TEXT, TEXT[] ) IS 'Wrapper to allow registration of patches without conflicts.';
    215 CREATE OR REPLACE FUNCTION _v.register_patch( TEXT ) RETURNS setof INT4 AS $$
    216     SELECT _v.register_patch( $1, NULL, NULL );
    217 $$ language sql;
    218 COMMENT ON FUNCTION _v.register_patch( TEXT ) IS 'Wrapper to allow registration of patches without requirements and conflicts.';
    219 
    220 CREATE OR REPLACE FUNCTION _v.unregister_patch( IN in_patch_name TEXT, OUT versioning INT4 ) RETURNS setof INT4 AS $$
    221 DECLARE
    222     i        INT4;
    223     t_text_a TEXT[];
    224 BEGIN
    225     -- Thanks to this we know only one patch will be applied at a time
    226     LOCK TABLE _v.patches IN EXCLUSIVE MODE;
    227 
    228     t_text_a := ARRAY( SELECT patch_name FROM _v.patches WHERE in_patch_name = ANY( requires ) );
    229     IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
    230         RAISE EXCEPTION 'Cannot uninstall %, as it is required by: %.', in_patch_name, array_to_string( t_text_a, ', ' );
    231     END IF;
    232 
    233     DELETE FROM _v.patches WHERE patch_name = in_patch_name;
    234     GET DIAGNOSTICS i = ROW_COUNT;
    235     IF i < 1 THEN
    236         RAISE EXCEPTION 'Patch % is not installed, so it can''t be uninstalled!', in_patch_name;
    237     END IF;
    238 
    239     RETURN;
    240 END;
    241 $$ language plpgsql;
    242 COMMENT ON FUNCTION _v.unregister_patch( TEXT ) IS 'Function to unregister patches in database. Dies if the patch is not registered, or if unregistering it would break dependencies.';
    243 
    244 CREATE OR REPLACE FUNCTION _v.assert_patch_is_applied( IN in_patch_name TEXT ) RETURNS TEXT as $$
    245 DECLARE
    246     t_text TEXT;
    247 BEGIN
    248     SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_patch_name;
    249     IF NOT FOUND THEN
    250         RAISE EXCEPTION 'Patch % is not applied!', in_patch_name;
    251     END IF;
    252     RETURN format('Patch %s is applied.', in_patch_name);
    253 END;
    254 $$ language plpgsql;
    255 COMMENT ON FUNCTION _v.assert_patch_is_applied( TEXT ) IS 'Function that can be used to make sure that patch has been applied.';
    256 
    257 CREATE OR REPLACE FUNCTION _v.assert_user_is_superuser() RETURNS TEXT as $$
    258 DECLARE
    259     v_super bool;
    260 BEGIN
    261     SELECT usesuper INTO v_super FROM pg_user WHERE usename = current_user;
    262     IF v_super THEN
    263         RETURN 'assert_user_is_superuser: OK';
    264     END IF;
    265     RAISE EXCEPTION 'Current user is not superuser - cannot continue.';
    266 END;
    267 $$ language plpgsql;
    268 COMMENT ON FUNCTION _v.assert_user_is_superuser() IS 'Function that can be used to make sure that patch is being applied using superuser account.';
    269 
    270 CREATE OR REPLACE FUNCTION _v.assert_user_is_not_superuser() RETURNS TEXT as $$
    271 DECLARE
    272     v_super bool;
    273 BEGIN
    274     SELECT usesuper INTO v_super FROM pg_user WHERE usename = current_user;
    275     IF v_super THEN
    276         RAISE EXCEPTION 'Current user is superuser - cannot continue.';
    277     END IF;
    278     RETURN 'assert_user_is_not_superuser: OK';
    279 END;
    280 $$ language plpgsql;
    281 COMMENT ON FUNCTION _v.assert_user_is_not_superuser() IS 'Function that can be used to make sure that patch is being applied using normal (not superuser) account.';
    282 
    283 CREATE OR REPLACE FUNCTION _v.assert_user_is_one_of(VARIADIC p_acceptable_users TEXT[] ) RETURNS TEXT as $$
    284 DECLARE
    285 BEGIN
    286     IF current_user = any( p_acceptable_users ) THEN
    287         RETURN 'assert_user_is_one_of: OK';
    288     END IF;
    289     RAISE EXCEPTION 'User is not one of: % - cannot continue.', p_acceptable_users;
    290 END;
    291 $$ language plpgsql;
    292 COMMENT ON FUNCTION _v.assert_user_is_one_of(TEXT[]) IS 'Function that can be used to make sure that patch is being applied by one of defined users.';
    293 
    294 COMMIT;