├── .github ├── CODEOWNERS ├── ISSUE_TEMPLATE.md └── PULL_REQUEST_TEMPLATE.md ├── sql ├── schema │ └── schema.sql ├── functions │ ├── create_all_functions.sql │ ├── partition_copy_fk_to_new_table.sql │ ├── partition_create_table_inherits_from_template.sql │ ├── partition_drop_detached_partition.sql │ ├── partition_get_last_partition_details.sql │ ├── partition_table.sql │ ├── partition_maintenance.sql │ ├── partition_copy_indexes_to_new_table.sql │ ├── partition_add_foreign_key_on_partitioned_table.sql │ ├── partition_detach_partition.sql │ ├── partition_add_concurrent_index_on_partitioned_table.sql │ ├── partition_add_constraints.sql │ ├── partition_inheritance.sql │ ├── partition_calculate_free_partitions.sql │ ├── partition_add_up_to_nr_of_free_partitions.sql │ └── partition_declarative.sql └── tables │ └── tables.sql ├── test ├── cleanup.sql ├── configuration.sql ├── run_functions.sql └── tables.sql ├── LICENSE └── README.md /.github/CODEOWNERS: -------------------------------------------------------------------------------- 1 | * @Adyen/dba 2 | -------------------------------------------------------------------------------- /sql/schema/schema.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA IF NOT EXISTS dba; 2 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE.md: -------------------------------------------------------------------------------- 1 | **Library version**: x.y.z 2 | **Description** 3 | 6 | -------------------------------------------------------------------------------- /.github/PULL_REQUEST_TEMPLATE.md: -------------------------------------------------------------------------------- 1 | **Description** 2 | 3 | 4 | **Tested scenarios** 5 | 6 | 7 | **Fixed issue**: 8 | -------------------------------------------------------------------------------- /test/cleanup.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS public.test_partition CASCADE; 2 | 3 | DROP TABLE IF EXISTS public.test_partition_date_template; 4 | DROP TABLE IF EXISTS public.test_partition_date CASCADE; 5 | 6 | DROP TABLE IF EXISTS public.test_partition_datetime CASCADE; 7 | 8 | DROP TABLE IF EXISTS public.test_partition_inh CASCADE; 9 | -------------------------------------------------------------------------------- /sql/functions/create_all_functions.sql: -------------------------------------------------------------------------------- 1 | \i sql/functions/partition_get_last_partition_details.sql 2 | \i sql/functions/partition_add_concurrent_index_on_partitioned_table.sql 3 | \i sql/functions/partition_add_constraints.sql 4 | \i sql/functions/partition_add_foreign_key_on_partitioned_table.sql 5 | \i sql/functions/partition_add_up_to_nr_of_free_partitions.sql 6 | \i sql/functions/partition_copy_fk_to_new_table.sql 7 | \i sql/functions/partition_copy_indexes_to_new_table.sql 8 | \i sql/functions/partition_create_table_inherits_from_template.sql 9 | \i sql/functions/partition_calculate_free_partitions.sql 10 | \i sql/functions/partition_declarative.sql 11 | \i sql/functions/partition_detach_partition.sql 12 | \i sql/functions/partition_drop_detached_partition.sql 13 | \i sql/functions/partition_inheritance.sql 14 | \i sql/functions/partition_table.sql 15 | -------------------------------------------------------------------------------- /test/configuration.sql: -------------------------------------------------------------------------------- 1 | insert into dba.partition_configuration values ('public', 'test_partition', json_build_object( 2 | 'auto-maintenance', true, 3 | 'date_constraint', json_build_object('marker', 'trip_date', 'constraint_column', 'trip_date'), 4 | 'nr', 4 5 | ) 6 | ); 7 | 8 | insert into dba.partition_configuration values ('public', 'test_partition_datetime', json_build_object( 9 | 'auto-maintenance', true, 10 | 'nr', 6, 11 | 'detach', '13 days', 12 | 'drop_detached', '4 days' 13 | ) 14 | ); 15 | 16 | INSERT INTO test_partition(id, trip_date) VALUES (7000000, '2001-01-01'); 17 | INSERT INTO test_partition(id, trip_date) VALUES (7999999, '2001-12-31'); 18 | 19 | -- Run partition_maintenance script 20 | \i sql/functions/partition_maintenance.sql 21 | 22 | -- Update the dba.detach_partitions table to simulate detached partitions over a period of time 23 | UPDATE dba.detached_partitions SET detached_date = range[1]::DATE + INTERVAL '2 weeks'; 24 | 25 | -- Run partition_maintenance script again to drop the detached partitions 26 | \i sql/functions/partition_maintenance.sql 27 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 Adyen 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 | -------------------------------------------------------------------------------- /sql/functions/partition_copy_fk_to_new_table.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function will enable copy_fk_to_new_table 3 | copy_fk_to_new_table has been designed to copy the foreign keys from one table to another. 4 | 5 | This is used during the creation of a new partition to ensure that the partition 6 | has the same foreign keys as the template table. 7 | 8 | PARAMETER TYPE DESCRIPTION 9 | v_schema TEXT the schema the tempalte lives in 10 | v_template TEXT the template to take the foreign keys from 11 | v_new_table TEXT the table to add the new foreign keys to 12 | */ 13 | 14 | CREATE OR REPLACE FUNCTION dba.partition_copy_fk_to_new_table(v_schema TEXT, v_template TEXT, v_new_table TEXT) 15 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 16 | 17 | DECLARE 18 | v_name TEXT; 19 | v_statement TEXT; 20 | 21 | BEGIN 22 | FOR v_name, v_statement IN 23 | SELECT conname, pg_get_constraintdef(oid) as statement from pg_constraint where conrelid=(LOWER(v_schema || '.' || v_template))::regclass and contype='f' 24 | LOOP 25 | EXECUTE format('ALTER TABLE ONLY %s.%s ADD CONSTRAINT %s %s;', v_schema, v_new_table, 26 | regexp_replace(v_name, LOWER(v_template), LOWER(v_new_table), 'g'), v_statement); 27 | END LOOP; 28 | 29 | RETURN TRUE; 30 | END 31 | $func$; 32 | -------------------------------------------------------------------------------- /sql/functions/partition_create_table_inherits_from_template.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function will create a new table and inherit the specifications 3 | from a template table. This is used as a way to create a new partition 4 | of a very large table. 5 | 6 | The final name of the table is constructed as follows: 7 | $(v_template_table)_$(v_suffix) 8 | 9 | PARAMETER TYPE DESCRIPTION 10 | v_schema TEXT schema the template table resides in 11 | v_template_table TEXT the template table 12 | v_suffix TEXT the suffix for the new table name 13 | 14 | Example: 15 | SELECT dba.partition_create_table_inherits_from_template('public', 'cardtobeprovisioned', '20220301_20220331'); 16 | */ 17 | 18 | CREATE OR REPLACE FUNCTION dba.partition_create_table_inherits_from_template(v_schema TEXT, v_template_table TEXT, v_suffix TEXT) 19 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 20 | 21 | DECLARE 22 | v_final_name TEXT := v_template_table || '_' || v_suffix; 23 | v_reloptions TEXT; 24 | 25 | BEGIN 26 | RAISE DEBUG 'Creating table % from template table % in schema %', v_template_table || '_' || v_suffix, v_template_table, v_schema USING ERRCODE='ADYEN'; 27 | EXECUTE format('CREATE TABLE %s.%s () INHERITS (%s.%s);', v_schema, v_final_name, v_schema, v_template_table); 28 | 29 | -- Copy the table storage parameters to the new partition 30 | EXECUTE format($sel$ 31 | SELECT array_to_string(reloptions, ',') from pg_class 32 | WHERE relname = '%I' and relnamespace::regnamespace::text='%I'; 33 | $sel$, v_template_table, v_schema) 34 | INTO v_reloptions; 35 | 36 | IF v_reloptions IS NOT NULL THEN 37 | EXECUTE format('ALTER TABLE %I.%I set (%s)', v_schema, v_final_name, v_reloptions); 38 | END IF; 39 | 40 | RETURN TRUE; 41 | END 42 | $func$; 43 | -------------------------------------------------------------------------------- /test/run_functions.sql: -------------------------------------------------------------------------------- 1 | -- Convert tables into partioned tables 2 | SELECT dba.partition_table('public','test_partition','id','1','7000000','1000000','native'); 3 | SELECT dba.partition_table('public','test_partition_date','trip_date','1970-01-01','2023-01-01','1 month','native', TRUE); 4 | SELECT dba.partition_table('public','test_partition_datetime','trip_date','1970-01-01','2023-01-01','1 week','native'); 5 | SELECT dba.partition_table('public','test_partition_inh','id','1','999999','1000','inheritance'); 6 | 7 | -- Create additional partitions for partitioned tables 8 | SELECT dba.partition_add_up_to_nr_of_free_partitions('public','test_partition', 3); 9 | SELECT dba.partition_add_up_to_nr_of_free_partitions('public','test_partition_date', 3); 10 | SELECT dba.partition_add_up_to_nr_of_free_partitions('public','test_partition_datetime', 3); 11 | 12 | -- Create different type of indexes to partitioned table 13 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['vendor_id']) \gexec 14 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition_date', ARRAY['lower(extra)', 'rate_code_id desc nulls first'], 'btree') \gexec 15 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition_datetime', ARRAY['id'], 'btree', true) \gexec 16 | 17 | -- Add foreign key to a partitioned table 18 | SELECT dba.partition_add_foreign_key_on_partitioned_table('public','test_partition_datetime', 'test_partition_test_date_time_test_partition_fk', 'test_partition', ARRAY['id'], ARRAY['id']) \gexec 19 | 20 | -- Create date constraints on a partition 21 | -- First insert some values 22 | INSERT INTO test_partition(id, trip_date) VALUES (8000000, '2000-01-01'); 23 | INSERT INTO test_partition(id, trip_date) VALUES (8999999, '2000-12-31'); 24 | -- Add the constraints 25 | SELECT dba.partition_add_constraints('public', 'test_partition', 'trip_date', 'trip_date'); 26 | 27 | -- Detach a partition 28 | SELECT dba.partition_detach_partition('public','test_partition_datetime', 'test_partition_datetime_20230102_20230109'); 29 | 30 | -- Drop detached table 31 | SELECT dba.partition_drop_detached_partition('public','test_partition_datetime', 'test_partition_datetime_20230102_20230109'); 32 | 33 | -------------------------------------------------------------------------------- /sql/functions/partition_drop_detached_partition.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function tries to drop a detached partition. The table must exits and be registered in dba.detached_partitions. 3 | After dropping the table, the row is removed from dba.detached_partitions. 4 | 5 | PARAMETER TYPE DESCRIPTION 6 | v_schema TEXT schema location for the table 7 | v_relname TEXT the table name of the parent table 8 | v_partition_name TEXT the name of the partition you would like to drop 9 | 10 | Example: 11 | SELECT dba.partition_drop_detached_partition('public','parent_table', 'child_table'); 12 | */ 13 | 14 | CREATE OR REPLACE FUNCTION dba.partition_drop_detached_partition(v_schema TEXT, v_relname_parent TEXT, v_partition_name TEXT) 15 | RETURNS BOOLEAN LANGUAGE plpgsql 16 | AS $func$ 17 | 18 | DECLARE 19 | V_ATTACH_LOCK_TIMEOUT CONSTANT INT := 1000 ; -- ms 20 | 21 | BEGIN 22 | v_schema:=LOWER(v_schema); 23 | v_relname_parent:=LOWER(v_relname_parent); 24 | v_partition_name:=LOWER(v_partition_name); 25 | 26 | -- Set a lock timeout for all statements in this function 27 | EXECUTE FORMAT('SET local lock_timeout TO %L', V_ATTACH_LOCK_TIMEOUT); 28 | 29 | -- Parent and child tables exists and combination is part of dba.detached_partitions 30 | PERFORM 1 FROM dba.detached_partitions dp 31 | JOIN pg_class parent ON parent.relname = parent_relname 32 | JOIN pg_class child ON child.relname = partition_relname 33 | WHERE 34 | schema = v_schema 35 | AND parent_relname = v_relname_parent 36 | AND partition_relname = v_partition_name 37 | AND parent.relnamespace::regnamespace::text = v_schema; 38 | 39 | IF NOT FOUND THEN 40 | RAISE EXCEPTION 'Table not found in dba.detached_partitions'; 41 | END IF; 42 | 43 | -- partition is not attached to any table 44 | PERFORM 1 45 | FROM pg_class child 46 | JOIN pg_inherits on inhrelid = oid 47 | WHERE 48 | child.relname = v_partition_name 49 | AND child.relnamespace::regnamespace::text = v_schema; 50 | 51 | IF FOUND THEN 52 | RAISE EXCEPTION 'Partition is attached to a table'; 53 | END IF; 54 | 55 | -- drop table 56 | RAISE NOTICE 'Dropping table'; 57 | EXECUTE format('DROP TABLE %I.%I', v_schema, v_partition_name); 58 | 59 | -- remove row from dba.detached_partitions 60 | EXECUTE FORMAT('DELETE FROM dba.detached_partitions WHERE schema = ''%I'' AND parent_relname = ''%I'' AND partition_relname = ''%I''' , v_schema, v_relname_parent, v_partition_name); 61 | 62 | RETURN TRUE; 63 | 64 | END 65 | $func$; 66 | -------------------------------------------------------------------------------- /sql/functions/partition_get_last_partition_details.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function returns the relation name and range for the last partition of a partitioned table. 3 | 4 | PARAMETER TYPE DESCRIPTION 5 | v_schema TEXT schema location for the table 6 | v_relname TEXT the normal table name 7 | v_range_identifier TEXT the identifier for a given range 8 | 9 | Example: 10 | SELECT dba.partition_get_last_partition_details('public','partitioned_table'); 11 | SELECT dba.partition_get_last_partition_details('public','partitioned_table', 'r1'); 12 | */ 13 | 14 | CREATE OR REPLACE FUNCTION dba.partition_get_last_partition_details(v_schema TEXT, v_relname TEXT, v_range_identifier TEXT DEFAULT NULL) 15 | RETURNS TABLE(v_childrelname TEXT, v_range TEXT ARRAY) LANGUAGE PLPGSQL AS $func$ 16 | 17 | DECLARE 18 | v_is_range BOOLEAN; 19 | v_coltype TEXT; 20 | 21 | BEGIN 22 | v_is_range := v_range_identifier IS NOT NULL; 23 | 24 | -- select the column type of the partitioning column. 25 | EXECUTE format($sel$ 26 | SELECT 27 | t.typname 28 | FROM 29 | (SELECT 30 | partrelid, 31 | unnest(partattrs) column_index 32 | FROM 33 | pg_partitioned_table) pt 34 | JOIN pg_class c on c.oid = pt.partrelid 35 | JOIN information_schema.columns col ON 36 | col.table_schema = c.relnamespace::regnamespace::text 37 | AND col.table_name = c.relname 38 | AND ordinal_position = pt.column_index 39 | JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid AND a.attname = col.column_name 40 | JOIN pg_catalog.pg_type t ON t.oid = a.atttypid 41 | WHERE 42 | LOWER(c.relname) = LOWER('%I') 43 | and LOWER(relnamespace::regnamespace::text)=LOWER('%I') 44 | $sel$, v_relname, v_schema) 45 | INTO v_coltype; 46 | 47 | RETURN QUERY EXECUTE FORMAT($sel$ 48 | SELECT 49 | LOWER(child.relname), 50 | regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*') as range 51 | FROM pg_inherits 52 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 53 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 54 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 55 | JOIN pg_namespace nmsp_parent ON nmsp_parent.oid = parent.relnamespace 56 | WHERE 57 | LOWER(nmsp_child.nspname)=LOWER('%I') 58 | AND LOWER(parent.relname)=LOWER('%I') 59 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 60 | AND (NOT '%I' or child.relname like '%I_' || %L || '_%%') 61 | AND NOT LOWER(child.relname) ~ 'mammoth' 62 | -- Order by the partition lower boundary limit, casted to the partition column type. 63 | ORDER BY (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*'))[1]::%s DESC 64 | LIMIT 1 65 | $sel$ , v_schema, v_relname, v_is_range, v_relname, v_range_identifier, v_coltype); 66 | END; 67 | $func$; 68 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # adyen-postgres-partitioning 2 | These functions are designed to create and maintain partitions in PostgreSQL with a minimal impact on the applicaton. The priority is to not impact the application. When multiple options are available the weakest lock possible is being used, when a heavy lock is required we use a timeout to prevent long lasting locks. 3 | 4 | Every function in this project starts with a detailed comment on what the function does and how to use it. 5 | 6 | ## Contributing 7 | We strongly encourage you to contribute to our repository. Find out more in our [contribution guidelines](https://github.com/Adyen/.github/blob/master/CONTRIBUTING.md) 8 | 9 | ## Requirements 10 | All function have been tested on postgres 13. 11 | 12 | ## Installation 13 | All function will be installed in the DBA schema. If you don't have this schema yet, create it by running sql/schema/schema.sql. 14 | 15 | You can add the individual functions directly on the database from `psql` with the `\i` command. Use `psql` to login on your database and run 16 | ```sql 17 | \i ..sql 18 | ``` 19 | N.B. Some functions use other functions and the script `partition_maintenance.sql` requires a set of tables to be created. 20 | 21 | ### Install all functions 22 | To create all the functions and the tables required to configure maintenance apply the following scripts in order from the root directory of the project 23 | sql/schema/schema.sql 24 | sql/tables/tables.sql 25 | sql/functions/create_all_functions.sql 26 | 27 | ### Test functions 28 | To test all functions run the following scripts from the project root folder 29 | test/tables.sql 30 | test/run_functions.sql 31 | test/configuration.sql 32 | test/cleanup.sql 33 | 34 | ## Usage 35 | The functions can be called as any other postgres function 36 | ```sql 37 | select dba.(arg1, arg2, ..., argN); 38 | ``` 39 | 40 | ## Documentation 41 | The functions in this project can 42 | 43 | - Partition an existing table. The origional table will not partitioned itself, but becomes the first partition 44 | - Add indexes to a partitioned table and all children 45 | - Add foreign keys to a partitioned table and all children 46 | - Add date constraints to a table partitioned on an integer column 47 | - Count the number of available, unused partitions 48 | - Get the details for the last partition 49 | - Add new partitions to a partitioned table. The new partitions will have the same properties as the latest available partition 50 | - Detach partitions from a partitioned table 51 | - Drop detached partitions 52 | 53 | Besides all the functions the project also contains the script `partition_maintenance.sql`. This scripts requires two tables being created 54 | - dba.partition_configuration 55 | - dba.detached_partitions 56 | 57 | The scripts performs the following tasks based on the configuration in the table `dba.partition_configuration`. 58 | - Add new partitions 59 | - Add date constraints 60 | - Detach partitions 61 | - Drop detached partitions after a cool-down period 62 | 63 | See the documentation within sql/tables/tables.sql for the configuration details. 64 | 65 | ## Support 66 | If you have a feature request, or spotted a bug or a technical problem, create a GitHub issue. 67 | 68 | ## License 69 | MIT license. For more information, see the LICENSE file. 70 | -------------------------------------------------------------------------------- /sql/functions/partition_table.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Converting traditional/normal table to a partitioned table with native or inheritance partitioning. 3 | Native partitioning supports ONLY by RANGE. 4 | 5 | The function will rename original table to $TABLE_mammoth, create an empty table 6 | called $TABLE and put it as main table, create another partition $TABLE_$v_endkey$v_interval 7 | 8 | From: test_partition 9 | to: 10 | - test_partition (parent table) 11 | - test_partition_mammoth 12 | - test_partition_20220401_20220430 13 | - test_partition_template (if the column is not in PK/unique index) 14 | 15 | PARAMETER TYPE DESCRIPTION 16 | v_schema TEXT schema location for the table 17 | v_tablename TEXT the normal table name 18 | v_keycolumn TEXT column name which the table will be partitioned based on 19 | v_startkey TEXT starting value for the the column in the original table; 20 | supports date & timestamp(tz) in YYYY-MM-DD format, and integers 21 | v_endkey TEXT LAST VALUE for inheritance, NEW VALUE for native *) 22 | v_interval TEXT length for the new partition table, e.g.: 1 month, 1 week, 1000000000, and so on 23 | v_type TEXT type of partitioning: native or inheritance 24 | v_nopk BOOLEAN set to true if the partition column is not in primary key or unique index; 25 | discouraged, unless application can ensure the data validity 26 | v_move_trg BOOLEAN set to true if you want to move triggers to newly partitioned table 27 | 28 | Example: 29 | SELECT dba.partition_table('public','test_partition','id','1','999999','1000','inheritance'); 30 | SELECT dba.partition_table('public','test_partition','id','1','1000000','1000','native'); 31 | SELECT dba.partition_table('public','test_partition_date','trip_date','1970-01-01','2023-01-01','1 month','native',TRUE,TRUE); 32 | 33 | Limitations: 34 | - In inheritance based partitioning, if the table is being referenced by other tables, 35 | the function will not work. 36 | - In native partitioning, referenced tables are fine. But, YOU HAVE TO RUN VALIDATE CONSTRAINT; 37 | we set them as not valid to make this function executed faster no matter the table size 38 | 39 | Caveats: 40 | Index names from the original $TABLE are not carried to any new tables, instead the names will follow 41 | postgres design, e.g.: $TABLE_col1_col2_col2_idx and so on 42 | 43 | Notes: 44 | *) Postgres native partitioning where the last value is exclusive 45 | */ 46 | CREATE OR REPLACE FUNCTION dba.partition_table(v_schemaname TEXT, v_tablename TEXT, v_keycolumn TEXT, v_startkey TEXT, v_endkey TEXT, v_interval TEXT, v_type TEXT, v_nopk BOOLEAN DEFAULT FALSE, v_move_trg BOOLEAN DEFAULT FALSE) 47 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 48 | BEGIN 49 | RAISE DEBUG 'Converting table % using % partitioning method', 50 | v_schemaname || '.' || v_tablename, v_type USING ERRCODE='ADYEN'; 51 | IF LOWER(v_type) = 'native' THEN 52 | PERFORM dba.partition_native(v_schemaname, v_tablename, v_keycolumn, v_startkey, v_endkey, v_interval, v_nopk, v_move_trg); 53 | ELSIF LOWER(v_type) = 'inheritance' THEN 54 | PERFORM dba.partition_inheritance(v_schemaname, v_tablename, v_keycolumn, v_startkey, v_endkey, v_interval); 55 | ELSE 56 | RAISE EXCEPTION '% IS NOT SUPPORTED.', v_type USING HINT = 'ADYEN: supported types are native and inheritance'; 57 | END IF; 58 | RETURN TRUE; 59 | END 60 | $func$; 61 | 62 | -------------------------------------------------------------------------------- /test/tables.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS public.test_partition CASCADE; 2 | CREATE TABLE public.test_partition ( 3 | id bigint, 4 | vendor_id integer, 5 | tpep_pickup_datetime text, 6 | tpep_dropoff_datetime text, 7 | passenger_count text, 8 | trip_distance text, 9 | pickup_longitude numeric, 10 | pickup_latitude numeric, 11 | rate_code_id text, 12 | store_and_fwd_flag text, 13 | dropoff_longitude numeric, 14 | dropoff_latitude numeric, 15 | payment_type text, 16 | fare_amount text, 17 | extra text, 18 | mta_tax text, 19 | tip_amount text, 20 | tolls_amount text, 21 | improvement_surcharge text, 22 | total_amount text, 23 | pickup_location_id text, 24 | dropoff_location_id text, 25 | congestion_surcharge text, 26 | junk1 text, 27 | junk2 text, 28 | trip_date date 29 | ); 30 | 31 | ALTER TABLE public.test_partition 32 | ADD CONSTRAINT test_partition_pkey PRIMARY KEY (id); 33 | 34 | DROP TABLE IF EXISTS public.test_partition_date_template; 35 | DROP TABLE IF EXISTS public.test_partition_date CASCADE; 36 | CREATE TABLE public.test_partition_date ( 37 | id bigint, 38 | vendor_id integer, 39 | tpep_pickup_datetime text, 40 | tpep_dropoff_datetime text, 41 | passenger_count text, 42 | trip_distance text, 43 | pickup_longitude numeric, 44 | pickup_latitude numeric, 45 | rate_code_id text, 46 | store_and_fwd_flag text, 47 | dropoff_longitude numeric, 48 | dropoff_latitude numeric, 49 | payment_type text, 50 | fare_amount text, 51 | extra text, 52 | mta_tax text, 53 | tip_amount text, 54 | tolls_amount text, 55 | improvement_surcharge text, 56 | total_amount text, 57 | pickup_location_id text, 58 | dropoff_location_id text, 59 | congestion_surcharge text, 60 | junk1 text, 61 | junk2 text, 62 | trip_date date 63 | ); 64 | 65 | ALTER TABLE public.test_partition_date 66 | ADD CONSTRAINT test_partition_date_pkey PRIMARY KEY (id); 67 | 68 | 69 | DROP TABLE IF EXISTS public.test_partition_datetime CASCADE; 70 | CREATE TABLE public.test_partition_datetime ( 71 | id bigint, 72 | vendor_id integer, 73 | tpep_pickup_datetime text, 74 | tpep_dropoff_datetime text, 75 | passenger_count text, 76 | trip_distance text, 77 | pickup_longitude numeric, 78 | pickup_latitude numeric, 79 | rate_code_id text, 80 | store_and_fwd_flag text, 81 | dropoff_longitude numeric, 82 | dropoff_latitude numeric, 83 | payment_type text, 84 | fare_amount text, 85 | extra text, 86 | mta_tax text, 87 | tip_amount text, 88 | tolls_amount text, 89 | improvement_surcharge text, 90 | total_amount text, 91 | pickup_location_id text, 92 | dropoff_location_id text, 93 | congestion_surcharge text, 94 | junk1 text, 95 | junk2 text, 96 | trip_date timestamp with time zone 97 | ); 98 | 99 | ALTER TABLE public.test_partition_datetime 100 | ADD CONSTRAINT test_partition_datetime_pkey PRIMARY KEY (id, trip_date); 101 | 102 | DROP TABLE IF EXISTS public.test_partition_inh CASCADE; 103 | CREATE TABLE public.test_partition_inh ( 104 | id bigint NOT NULL, 105 | vendor_id integer, 106 | tpep_pickup_datetime text, 107 | tpep_dropoff_datetime text, 108 | passenger_count text, 109 | trip_distance text, 110 | pickup_longitude numeric, 111 | pickup_latitude numeric, 112 | rate_code_id text, 113 | store_and_fwd_flag text, 114 | dropoff_longitude numeric, 115 | dropoff_latitude numeric, 116 | payment_type text, 117 | fare_amount text, 118 | extra text, 119 | mta_tax text, 120 | tip_amount text, 121 | tolls_amount text, 122 | improvement_surcharge text, 123 | total_amount text, 124 | pickup_location_id text, 125 | dropoff_location_id text, 126 | congestion_surcharge text, 127 | junk1 text, 128 | junk2 text, 129 | trip_date date 130 | ); 131 | 132 | ALTER TABLE public.test_partition_inh 133 | ADD CONSTRAINT test_partition_inh_pkey PRIMARY KEY (id); 134 | -------------------------------------------------------------------------------- /sql/functions/partition_maintenance.sql: -------------------------------------------------------------------------------- 1 | -- Create new partitions based on number 2 | SELECT 3 | dba.partition_add_up_to_nr_of_free_partitions( 4 | relnamespace::regnamespace::text, 5 | par.relname, 6 | GREATEST(3, CAST(configuration ->> 'nr' AS INT) + 2)) 7 | FROM pg_partitioned_table pt 8 | JOIN pg_class par ON par.oid = pt.partrelid 9 | JOIN dba.partition_configuration cfg ON 10 | LOWER(cfg.schema_name) = LOWER(relnamespace::regnamespace::text) 11 | AND LOWER(cfg.table_name) = LOWER(par.relname) 12 | WHERE 13 | CAST(configuration ->> 'auto-maintenance' AS boolean) 14 | AND pt.partstrat = 'r'; 15 | 16 | -- Add date constraints to partitions 17 | with config as ( 18 | SELECT q.schema_name, q.table_name, d.key, d.value::json 19 | FROM dba.partition_configuration q 20 | JOIN json_each_text(configuration) d ON true 21 | ORDER BY 1, 2 22 | ), 23 | constraint_set as ( 24 | select * 25 | from config 26 | where key = 'date_constraint' 27 | ) 28 | select dba.partition_add_constraints( 29 | constraint_set.schema_name, 30 | constraint_set.table_name, 31 | x.marker, 32 | x.constraint_column) 33 | from constraint_set, json_to_record(constraint_set.value) as x(constraint_column text, marker text); 34 | 35 | -- Detach partitions 36 | with config as ( 37 | SELECT q.schema_name, q.table_name, d.key, d.value::text 38 | FROM dba.partition_configuration q 39 | JOIN json_each_text(configuration) d ON true 40 | ORDER BY 1, 2 41 | ), 42 | detach_set as ( 43 | select * 44 | from config 45 | where key = 'detach' 46 | ), 47 | -- Only process tables partitioned on a date or timestamp 48 | detach_date_set as MATERIALIZED ( 49 | SELECT 50 | schema_name, 51 | detach_set.table_name, 52 | LOWER(child.relname) as partition_name, 53 | detach_set.value::interval as detach_interval, 54 | (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*'))[2] as upper_boundary 55 | FROM detach_set 56 | JOIN pg_class parent ON parent.relname = detach_set.table_name 57 | JOIN pg_inherits ON pg_inherits.inhparent = parent.oid 58 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 59 | JOIN pg_namespace nmsp_parent ON nmsp_parent.oid = parent.relnamespace 60 | JOIN (SELECT 61 | partrelid, 62 | unnest(partattrs) column_index 63 | FROM 64 | pg_partitioned_table) pt ON pt.partrelid = parent.oid 65 | JOIN information_schema.columns col ON 66 | col.table_schema = detach_set.schema_name 67 | AND col.table_name = parent.relname 68 | AND ordinal_position = pt.column_index 69 | JOIN pg_catalog.pg_attribute a ON a.attrelid = parent.oid AND a.attname = col.column_name 70 | JOIN pg_catalog.pg_type t ON t.oid = a.atttypid 71 | WHERE 72 | (t.typname ~ 'timestamp' OR t.typname ~ 'date') 73 | AND LOWER(nmsp_parent.nspname)=LOWER(detach_set.schema_name) 74 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 75 | AND NOT LOWER(child.relname) ~ 'mammoth' 76 | ) 77 | SELECT 78 | schema_name, 79 | detach_date_set.table_name, 80 | partition_name, 81 | dba.partition_detach_partition(schema_name, detach_date_set.table_name, partition_name) FROM detach_date_set 82 | WHERE 83 | detach_date_set.upper_boundary::DATE < ( CURRENT_DATE - detach_interval )::DATE 84 | ORDER BY schema_name, detach_date_set.table_name, upper_boundary::DATE ASC ; 85 | 86 | -- Drop detached tables 87 | WITH config AS ( 88 | SELECT q.schema_name, q.table_name, d.key, d.value::text 89 | FROM dba.partition_configuration q 90 | JOIN json_each_text(configuration) d ON true 91 | ORDER BY 1, 2 92 | ), 93 | drop_detach_set AS ( 94 | SELECT * 95 | FROM config 96 | WHERE key = 'drop_detached' 97 | ) 98 | SELECT 99 | schema_name, 100 | table_name, 101 | partition_relname 102 | ,dba.partition_drop_detached_partition(schema_name, table_name, partition_relname) as is_dropped 103 | FROM drop_detach_set 104 | LEFT JOIN LATERAL ( 105 | SELECT partition_relname FROM dba.detached_partitions 106 | WHERE parent_relname = drop_detach_set.table_name 107 | AND detached_date <= current_date - GREATEST(drop_detach_set.value::interval, '4 days'::interval) 108 | AND schema = drop_detach_set.schema_name 109 | ) drop_table_set ON 1=1 110 | where partition_relname is not null; -------------------------------------------------------------------------------- /sql/functions/partition_copy_indexes_to_new_table.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function will duplicate primary key and other indexes 3 | from template table 4 | 5 | PARAMETER TYPE DESCRIPTION 6 | v_schema TEXT schema the template table resides in 7 | v_template TEXT template to take the indexes from 8 | v_new_table TEXT table to apply indexes to 9 | v_randomize BOOLEAN option to randomize index name, default TRUE 10 | 11 | Example: 12 | SELECT dba.partition_copy_indexes_to_new_table('public', 'test_partition_inh', 'test_partition_inh_20220301_20220331'); 13 | SELECT dba.partition_copy_indexes_to_new_table('public', 'test_partition_inh', 'test_partition_inh_20220301_20220331', false); 14 | */ 15 | 16 | CREATE OR REPLACE FUNCTION dba.partition_copy_indexes_to_new_table(v_schema TEXT, v_template TEXT, v_new_table TEXT, v_randomize BOOLEAN DEFAULT TRUE) 17 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 18 | 19 | DECLARE 20 | v_row RECORD; 21 | v_final_creation_statement TEXT; 22 | v_newindexname TEXT; 23 | 24 | BEGIN 25 | RAISE DEBUG 'Copying indexes FROM % TO %', v_schema ||'.'|| v_template, v_schema ||'.'|| v_new_table USING ERRCODE='ADYEN'; 26 | FOR v_row IN 27 | WITH indexes AS ( 28 | SELECT indexdef, indexname FROM pg_indexes 29 | WHERE schemaname = LOWER(v_schema) 30 | AND tablename = LOWER(v_template) 31 | ) 32 | SELECT indexdef, indisprimary, indexname FROM indexes 33 | JOIN pg_class ON pg_class.relname = indexes.indexname 34 | JOIN pg_index ON pg_class.oid = pg_index.indexrelid 35 | JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace 36 | WHERE pg_namespace.nspname = LOWER(v_schema) 37 | LOOP 38 | IF v_row.indisprimary IS TRUE THEN 39 | IF length(v_new_table) > 58 THEN 40 | v_newindexname := substring(LOWER(v_new_table), 1, 58); 41 | ELSE 42 | v_newindexname := LOWER(v_new_table); 43 | END IF; 44 | v_final_creation_statement := regexp_replace(v_row.indexdef,'.*btree','ALTER TABLE ONLY ' || LOWER(v_schema) || '.' || LOWER(v_new_table) || ' ADD CONSTRAINT ' || LOWER(v_newindexname) || '_pkey' || ' PRIMARY KEY' ) || ';'; 45 | IF ( 46 | SELECT indisprimary FROM pg_indexes 47 | JOIN pg_class ON pg_class.relname = pg_indexes.indexname 48 | JOIN pg_index ON pg_class.oid = pg_index.indexrelid 49 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace AND pg_namespace.nspname = LOWER(v_schema)) 50 | WHERE schemaname = LOWER(v_schema) AND tablename = LOWER(v_new_table) AND indisprimary = TRUE 51 | ) IS TRUE THEN 52 | RAISE NOTICE 'PRIMARY KEY exists, skipping' USING ERRCODE='ADYEN'; 53 | ELSE 54 | RAISE DEBUG 'Creating primary key using: %', v_final_creation_statement USING ERRCODE='ADYEN'; 55 | EXECUTE format(v_final_creation_statement); 56 | END IF; 57 | ELSE 58 | IF LOWER(v_row.indexname) ~ LOWER(v_template) THEN 59 | v_newindexname := regexp_replace(v_row.indexname, LOWER(v_template), LOWER(v_new_table)); 60 | ELSE 61 | -- this is forced because we need table name in indexname 62 | -- otherwise it can cause further break down 63 | IF v_randomize THEN 64 | v_newindexname := substring(LOWER(v_new_table), 1, 56) || '_idx_' || trunc(random() * 98 + 1); 65 | ELSE 66 | v_newindexname := substring(LOWER(v_new_table), 1, 59) || '_idx'; 67 | END IF; 68 | END IF; 69 | IF length(v_newindexname) > 63 THEN 70 | IF v_randomize THEN 71 | v_newindexname := substring(LOWER(v_newindexname), 1, 56) || '_idx' || trunc(random() * 98 + 1); 72 | ELSE 73 | v_newindexname := substring(LOWER(v_newindexname), 1, 59) || '_idx'; 74 | END IF; 75 | END IF; 76 | v_final_creation_statement := regexp_replace(v_row.indexdef, LOWER(v_schema) || '.' || LOWER(v_template), LOWER(v_schema) || '.' || LOWER(v_new_table)); 77 | v_final_creation_statement := regexp_replace(v_final_creation_statement, LOWER(v_row.indexname), LOWER(v_newindexname)); 78 | RAISE DEBUG 'Creating an index using: %', v_final_creation_statement USING ERRCODE='ADYEN'; 79 | EXECUTE format(v_final_creation_statement); 80 | END IF; 81 | END LOOP; 82 | 83 | RETURN TRUE; 84 | END 85 | $func$; 86 | -------------------------------------------------------------------------------- /sql/functions/partition_add_foreign_key_on_partitioned_table.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function generates a set of statements to create add foreign key not valid statements for all partitions of a 3 | partitioned tables and a create foreign key statement for the parent table. If a _template exists a 4 | create foreign key statement is returned for this table as wel. It does not execute these 5 | statements. 6 | 7 | PARAMETER TYPE DESCRIPTION 8 | v_schema TEXT schema location for the table 9 | v_table TEXT the partitioned child table on which to create the foreign key 10 | v_constraint_name TEXT the name of the constraint. Equal for all children and parent 11 | v_parent TEXT the name of the parent table 12 | v_child_column_names TEXT[] the column names of the child table 13 | v_parent_column_names TEXT[] the column names of the parent table 14 | 15 | Example: 16 | SELECT dba.partition_add_foreign_key_on_partitioned_table('public','test_partition', 'table_fk', 'table_parent', ARRAY['id'], ARRAY['id']); 17 | 18 | Returns: 19 | A table containing the following statements in order 20 | - A add constraint not valid statement every child table 21 | - A validate constraint statement every child table 22 | - A add constraint statement for the parent table 23 | */ 24 | 25 | CREATE OR REPLACE FUNCTION dba.partition_add_foreign_key_on_partitioned_table(v_schema TEXT, v_table TEXT, v_constraint_name TEXT, v_parent TEXT, v_child_column_names TEXT[], v_parent_column_names TEXT[]) 26 | RETURNS table(stmt text) LANGUAGE plpgsql AS $func$ 27 | 28 | DECLARE 29 | v_total_childs INT; 30 | 31 | BEGIN 32 | v_schema:=LOWER(v_schema); 33 | v_table:=LOWER(v_table); 34 | 35 | -- Create a temporary table to store the results. 36 | CREATE TEMP TABLE IF NOT EXISTS temp_partition_concurrent_indexes (order_number int, table_name text, index_name text) 37 | ON COMMIT DELETE ROWS; 38 | 39 | -- List all the child partitions 40 | -- The name of the temp table is not exactly spot on, but I don't want to create a new temp table for this function. 41 | EXECUTE FORMAT ($sql$ 42 | INSERT INTO temp_partition_concurrent_indexes ( 43 | SELECT 44 | 1 AS order_number, 45 | child.relname as table_name, 46 | null AS index_name 47 | FROM pg_inherits 48 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 49 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 50 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 51 | WHERE 52 | LOWER(parent.relnamespace::regnamespace::text) = LOWER('%I') 53 | AND LOWER(parent.relname)=LOWER('%I')) 54 | $sql$, v_schema, v_table); 55 | 56 | EXECUTE FORMAT ($sql$ 57 | INSERT INTO temp_partition_concurrent_indexes values (2, '%I', null) 58 | $sql$, v_table); 59 | 60 | -- Check if _template table exists 61 | PERFORM 1 62 | FROM pg_class c 63 | WHERE 64 | LOWER(c.relname) = LOWER(v_table || '_template') 65 | AND LOWER(c.relnamespace::regnamespace::text) = LOWER(v_schema); 66 | 67 | IF FOUND THEN 68 | EXECUTE FORMAT ($sql$ 69 | INSERT INTO temp_partition_concurrent_indexes values (3, '%I_template', null) 70 | $sql$, v_table, v_constraint_name); 71 | END IF; 72 | 73 | SELECT COUNT(*) FROM temp_partition_concurrent_indexes where order_number = 1 74 | INTO v_total_childs; 75 | 76 | RETURN QUERY 77 | EXECUTE FORMAT($sql$ 78 | (SELECT 'alter table %I.' || table_name || ' add constraint %I foreign key (%I) references %I(%I) not valid;' FROM temp_partition_concurrent_indexes WHERE order_number = 1) 79 | UNION ALL 80 | (SELECT '/* Validating constraint ' || ROW_NUMBER() OVER (ORDER BY table_name) || ' of %s */ alter table %I.' || table_name || ' validate constraint %I;' FROM temp_partition_concurrent_indexes WHERE order_number = 1 ORDER BY table_name) 81 | UNION ALL 82 | (SELECT 'alter table %I.%I add constraint %I foreign key (%I) references %I(%I);') 83 | UNION ALL 84 | (SELECT 'alter table %I.' || table_name || ' add constraint %I foreign key (%I) references %I(%I);' FROM temp_partition_concurrent_indexes WHERE order_number = 3) 85 | $sql$, 86 | v_schema, v_constraint_name, LOWER(array_to_string(v_child_column_names, ',')), v_parent, LOWER(array_to_string(v_parent_column_names, ',')), 87 | v_total_childs, v_schema, v_constraint_name, 88 | v_schema, v_table, v_constraint_name, LOWER(array_to_string(v_child_column_names, ',')), v_parent, LOWER(array_to_string(v_parent_column_names, ',')), 89 | v_schema, v_constraint_name, LOWER(array_to_string(v_child_column_names, ',')), v_parent, LOWER(array_to_string(v_parent_column_names, ',')) 90 | ); 91 | END 92 | $func$; 93 | -------------------------------------------------------------------------------- /sql/tables/tables.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This table contains the configuration for partitioned tables. 3 | It is possible to configure the following options 4 | - Enable auto maintenance for this table 5 | - The number of free, available partitions 6 | - Add constraints to partitions 7 | - Detach partitions 8 | - Drop detached partitions 9 | 10 | Automatic maintenance 11 | --------------------- 12 | If you want the maintenance script to do maintenance on the partitioned tables, you have to 13 | specify the schema, table name and set the 'auto-maintenance' flag explicitly to true. 14 | 15 | insert into dba.partition_configuration values ('public', 'test_partition', json_build_object( 16 | 'auto-maintenance', true 17 | ) 18 | ); 19 | 20 | Without any further configuration the maintenance script will now create new partitions for your 21 | partitioned table until there are at least 22 | - three free, available partitions for a table partitioned on any integer type 23 | - three partitions with a starting date after today for a table partitioned on a date/timestamp type 24 | 25 | Number of free, available partitions 26 | ------------------------------------ 27 | If you want more than three unused, available partitions for a partitioned table you can configure 28 | this number with the 'nr' option. This might be useful when using daily partitions and you want to 29 | have at least a week of partitions available to be on the safe side at all times. 30 | 31 | insert into dba.partition_configuration values ('public', 'test_partition', json_build_object( 32 | 'auto-maintenance', true, 33 | 'nr', 6 34 | ) 35 | ); 36 | 37 | In this example the script will create partitions for the partitioned table test_partition until there 38 | are six unused, available partitions. 39 | 40 | Add constraints 41 | --------------- 42 | The script can also add date constraints on a table partitioned on an integer column. This is useful 43 | when the table is partitioned on a integer type, but also accessed based on a date type. 44 | 45 | A check constraint with a minimal date is added as soon as a partition contains at least one row. 46 | A check constraint with a maximum date is added as soon as a row matching the upper boundary of 47 | the partition has been added. 48 | 49 | N.B. This method only works with increasing, non changing values. 50 | 51 | To configure this constraints use a json object with a marker and column name on which the constraint 52 | is required. 53 | 54 | insert into dba.partition_configuration values ('public', 'test_partition', json_build_object( 55 | 'auto-maintenance', true, 56 | 'date_constraint', json_build_object('marker', 'trip_date', 'constraint_column', 'trip_date') 57 | ) 58 | ); 59 | 60 | In this example the following constraints will be added to the children of table 'test_partition' 61 | - _trip_date_min 62 | - _trip_date_max 63 | 64 | The min constraint will be based on min(), the max constraint on the 65 | max( 'DEFAULT' 79 | AND NOT LOWER(child.relname) ~ 'mammoth' 80 | -- Order by the partition lower boundary limit, casted to the partition column type. 81 | ORDER BY (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*'))[1]::%s asc 82 | LIMIT 1 83 | $sel$ , v_schema, v_relname_parent, v_coltype) 84 | into v_oldest_partition_relname, v_last_range; 85 | 86 | -- If the given partition name is not the name of the oldest partition we throw an exception 87 | -- If the given partition name doesn't exist, there is no match and we throw the same exception 88 | IF NOT v_oldest_partition_relname = v_partition_name THEN 89 | RAISE NOTICE 'Use select dba.partition_detach_partition(''%'', ''%'', ''%'', FALSE) to detach a partition other than the oldest one', v_schema, v_relname_parent, v_partition_name; 90 | 91 | RAISE EXCEPTION '% is not the oldest partition', v_partition_name; 92 | END IF; 93 | ELSE 94 | EXECUTE FORMAT($sel$ 95 | SELECT 96 | regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*') as range 97 | FROM pg_inherits 98 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 99 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 100 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 101 | JOIN pg_namespace nmsp_parent ON nmsp_parent.oid = parent.relnamespace 102 | WHERE 103 | LOWER(nmsp_parent.nspname)=LOWER('%I') 104 | AND LOWER(parent.relname)=LOWER('%I') 105 | AND LOWER(child.relname) = LOWER('%I') 106 | $sel$ , v_schema, v_relname_parent, v_partition_name) 107 | INTO v_last_range; 108 | 109 | IF ( v_last_range IS NULL ) THEN 110 | RAISE EXCEPTION '% is not a partition of %', v_partition_name, v_relname_parent; 111 | END IF; 112 | 113 | RAISE NOTICE '!!! Detaching a non-oldest partition !!!'; 114 | END IF; 115 | 116 | -- Detach the partition 117 | RAISE NOTICE 'Detaching partition % from table %', v_schema || '.' || v_partition_name, v_schema || '.' || v_relname_parent; 118 | 119 | -- Try to detach the partition from the parent. We need a AccessExclusiveLock when a default partition exists. We 120 | -- try to get a lock for V_ATTACH_LOCK_TIMEOUT ms. If we can't get the lock, we wait V_ATTACH_RETRY_SLEEP seconds 121 | -- and try again for a maximum of V_ATTACH_RETRIES times. If we didn't succeed in detaching the partition the 122 | -- function returns 'false'. 123 | FOR loop_cnt in 1..V_ATTACH_RETRIES LOOP 124 | BEGIN 125 | -- Detach the partition from the parent table 126 | EXECUTE format('ALTER TABLE %I.%I DETACH PARTITION %I.%I', 127 | v_schema, v_relname_parent, v_schema, v_partition_name); 128 | 129 | -- Detaching succeeded. Exit the loop. 130 | EXIT; 131 | 132 | EXCEPTION 133 | WHEN lock_not_available THEN 134 | RAISE NOTICE 'Lock not available %', loop_cnt; 135 | 136 | IF loop_cnt = V_ATTACH_RETRIES THEN 137 | RAISE NOTICE 'Detaching table failed'; 138 | 139 | RETURN FALSE; 140 | END IF; 141 | 142 | perform pg_sleep(V_ATTACH_RETRY_SLEEP); 143 | END; 144 | END LOOP; 145 | 146 | -- Do some book keeping: old parent, old partition name, old range, date of detaching 147 | INSERT INTO dba.detached_partitions VALUES (v_schema, v_relname_parent, v_partition_name, v_last_range, CURRENT_DATE); 148 | 149 | RETURN TRUE; 150 | 151 | END 152 | $func$; 153 | -------------------------------------------------------------------------------- /sql/functions/partition_add_concurrent_index_on_partitioned_table.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function generates a set of statements to create concurrent indexes on all partitions of a partitioned tables and a 3 | create index statement for the parent table. In case the table is partitioned on a column which is not part of the 4 | primary key, also a create index statement for the _template is returned as wel. It does not execute these 5 | statements. 6 | 7 | The function tries to find a unique index name in the form of _[1-9]_idx. If no unique name 8 | can be found, the name with a nine in it will we returned. Executing this statement will fail with a duplicate index error. 9 | 10 | When a unique index has to be created, we only add this index on the parent table when the partition column is included 11 | in the index. Otherwise we would get an error. 12 | 13 | PARAMETER TYPE DESCRIPTION 14 | v_schema TEXT schema location for the table 15 | v_tablename TEXT the parent table name 16 | v_columns TEXT[] the columns to create the index on including the names the operator class parameters such as desc, nulls first, nulls distinct 17 | v_method TEXT the name of the index method, default btree. Possible other values: hash, gist, spgist, gin, brin 18 | v_is_unique BOOLEAN default false. Indicate the index has to be unique 19 | 20 | Example: 21 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['column_1', 'column_2']); 22 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['lower(column_1)', 'column_2 desc nulls first'], 'gin'); 23 | SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['lower(column_1)', 'column_2 desc nulls first'], 'gin', true); 24 | 25 | Returns: 26 | A table containing the following statements in order 27 | - A create index concurrently statement for every child table 28 | - A create index statement for the parent table 29 | - A create index statement for the parent_template table when this table exists 30 | */ 31 | 32 | CREATE OR REPLACE FUNCTION dba.partition_add_concurrent_index_on_partitioned_table(v_schema TEXT, v_table TEXT, v_columns TEXT[], v_method TEXT default 'btree', v_is_unique boolean DEFAULT FALSE) 33 | RETURNS table(stmt text) LANGUAGE plpgsql AS $func$ 34 | 35 | DECLARE 36 | v_indexname TEXT; 37 | v_row RECORD; 38 | v_row_count INT; 39 | v_column_names TEXT[]; 40 | v_total_indexes INT; 41 | v_column_name TEXT; 42 | 43 | BEGIN 44 | v_schema:=LOWER(v_schema); 45 | v_table:=LOWER(v_table); 46 | 47 | -- When creating a unique index we need to know the partition column 48 | IF (v_is_unique) THEN 49 | EXECUTE format($sel$ 50 | SELECT 51 | LOWER(col.column_name) 52 | FROM 53 | (SELECT 54 | partrelid, 55 | unnest(partattrs) column_index 56 | FROM 57 | pg_partitioned_table) pt 58 | JOIN pg_class c on c.oid = pt.partrelid 59 | JOIN information_schema.columns col ON 60 | col.table_schema = c.relnamespace::regnamespace::text 61 | AND col.table_name = c.relname 62 | AND ordinal_position = pt.column_index 63 | WHERE 64 | c.relname = '%I' 65 | and relnamespace::regnamespace::text='%I' 66 | $sel$, v_table, v_schema) 67 | INTO v_column_name; 68 | END IF; 69 | 70 | -- separate the column names from the rest of the arguments like functions and operators like 'desc', 'nulls first', etc 71 | SELECT ARRAY (SELECT regexp_replace(split_part(UNNEST(v_columns), ' ', 1), '.*\((.*)\)', '\1')) 72 | INTO v_column_names; 73 | 74 | IF (SELECT LOWER(v_method) NOT IN ('btree', 'hash', 'gist', 'spgist', 'gin', 'brin') ) THEN 75 | RAISE EXCEPTION 'Index method % is not supported', v_method; 76 | END IF; 77 | 78 | -- Create a temporary table to store the results. 79 | CREATE TEMP TABLE IF NOT EXISTS temp_partition_concurrent_indexes (order_number int, table_name text, index_name text) 80 | ON COMMIT DELETE ROWS; 81 | 82 | -- List all the child partitions 83 | EXECUTE FORMAT ($sql$ 84 | INSERT INTO temp_partition_concurrent_indexes ( 85 | SELECT 86 | 1 AS order_number, 87 | child.relname as table_name, 88 | substring(LOWER(child.relname) || '_%I' , 1, 59) || '_idx' AS index_name 89 | FROM pg_inherits 90 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 91 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 92 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 93 | WHERE 94 | LOWER(parent.relnamespace::regnamespace::text) = LOWER('%I') 95 | AND LOWER(parent.relname)=LOWER('%I')) 96 | $sql$, 97 | LOWER(array_to_string(v_column_names, '_')), v_schema, v_table); 98 | 99 | -- Add the parent table if a non-unique index OR it is a unique index, but the index contains the partition column 100 | IF ( ( NOT v_is_unique) OR ( v_is_unique AND v_column_name=ANY(lower(v_columns::text)::text[]) ) )THEN 101 | EXECUTE FORMAT ($sql$ 102 | INSERT INTO temp_partition_concurrent_indexes values (2, '%I', substring(LOWER('%I') || '_%I', 1, 59) || '_idx') 103 | $sql$, v_table, v_table, LOWER(array_to_string(v_column_names, '_'))); 104 | END IF; 105 | 106 | -- Check if _template table exists 107 | perform 1 108 | FROM pg_class c 109 | WHERE LOWER(c.relname) = LOWER(v_table || '_template') AND LOWER(c.relnamespace::regnamespace::text) = LOWER(v_schema); 110 | 111 | IF FOUND THEN 112 | EXECUTE FORMAT ($sql$ 113 | INSERT INTO temp_partition_concurrent_indexes values (3, '%I_template', substring(LOWER('%I_template') || '_%I', 1, 59) || '_idx') 114 | $sql$, v_table, v_table, LOWER(array_to_string(v_column_names, '_'))); 115 | END IF; 116 | 117 | FOR v_row IN SELECT * FROM temp_partition_concurrent_indexes LOOP 118 | EXECUTE FORMAT ($sql$ 119 | SELECT '1' FROM pg_class c, pg_namespace n WHERE c.relnamespace = n.oid 120 | AND relname = '%I' AND nspname = '%I' AND lower(relkind) = 'i' 121 | $sql$, v_row.index_name, v_schema) ; 122 | 123 | GET DIAGNOSTICS v_row_count = ROW_COUNT; 124 | 125 | IF v_row_count = 0 THEN 126 | -- Index name is unique. We are done. 127 | continue; 128 | ELSE 129 | -- An index with this name already exists. Remove the suffix and add a number at the end. 130 | -- After number 9 we give up and executing the create index statement will fail. 131 | FOR counter in 1..9 LOOP 132 | IF LENGTH(v_row.index_name) = 64 THEN 133 | -- We should not cross the 64 characters when adding a number. Remove the suffix and one character. 134 | v_indexname := left(v_row.index_name , -5) || counter || '_idx'; 135 | ELSE 136 | v_indexname := left(v_row.index_name , -4) || counter || '_idx'; 137 | END IF; 138 | 139 | RAISE DEBUG 'Testing index name % for uniqueness', v_indexname; 140 | 141 | EXECUTE FORMAT ($sql$ 142 | SELECT '1' FROM pg_class c, pg_namespace n WHERE c.relnamespace = n.oid 143 | AND relname = '%I' AND nspname = '%I' AND lower(relkind) = 'i' 144 | $sql$, v_indexname, v_schema) ; 145 | 146 | GET DIAGNOSTICS v_row_count = ROW_COUNT; 147 | 148 | IF v_row_count = 0 THEN 149 | -- We have found a unique index name. Update the temp table with this name. 150 | EXECUTE FORMAT($sql$ UPDATE temp_partition_concurrent_indexes SET index_name = '%I' WHERE table_name = '%I' 151 | $sql$, v_indexname, v_row.table_name); 152 | 153 | exit; 154 | END IF; 155 | END LOOP; 156 | END IF; 157 | END LOOP; 158 | 159 | SELECT COUNT(*) FROM temp_partition_concurrent_indexes 160 | INTO v_total_indexes; 161 | 162 | RETURN QUERY 163 | EXECUTE format($sql$ 164 | SELECT '/* Creating index ' || row_number() over (order by order_number, index_name) || ' of %s */ create ' || 165 | CASE WHEN '%I'::boolean THEN 'unique ' ELSE '' END || 166 | 'index ' || 167 | CASE WHEN order_number = 1 THEN 'concurrently ' ELSE '' END || 168 | index_name || ' on %I.' || 169 | table_name || ' using %I (%s);' 170 | FROM temp_partition_concurrent_indexes 171 | ORDER BY order_number, index_name 172 | $sql$, v_total_indexes, v_is_unique, v_schema, v_method, LOWER(array_to_string(v_columns, ', '))); 173 | END 174 | $func$; 175 | -------------------------------------------------------------------------------- /sql/functions/partition_add_constraints.sql: -------------------------------------------------------------------------------- 1 | /* 2 | When a table is partitioned based an integer, but queries are using a date or timestamp column for selecting records we 3 | can add a check constraint on this date/timestamp column to help the optimizer prune unrelevant partitions. 4 | 5 | This function adds 6 | - A check constraint based on the current minimal value of the date/timestamp column as soon as there is at 7 | least one row in the partition. 8 | - A check constraint based on the current maximam value of the date/timestamp column as soon as there is a record matching 9 | the upper boundary of the partition (partition is full). 10 | 11 | In order for a table to be selected by this function it must satisfy the following conditions 12 | - The table is partitioned based on an integer column 13 | - The check constraint has to be applied on a date or timestamp column 14 | 15 | The function will create check constraints with names 16 | - __constraint_min 17 | - __constraint_max 18 | 19 | For example 20 | - test_partition_1000_2000_date_constraint_min 21 | - test_partition_1000_2000_date_constraint_max 22 | 23 | Example: 24 | SELECT dba.partition_add_constraints('public', 'test_partition', 'trip_date', 'trip_date'); 25 | */ 26 | 27 | CREATE OR REPLACE FUNCTION dba.partition_add_constraints(v_schema TEXT, v_relname TEXT, v_marker TEXT, v_column_name TEXT) 28 | RETURNS VOID LANGUAGE plpgsql AS $func$ 29 | 30 | DECLARE 31 | v_boundary_regex CONSTANT TEXT := '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*'; 32 | v_coltype TEXT; 33 | v_partition_column_name TEXT; 34 | v_child RECORD; 35 | v_partition_is_full BOOLEAN; 36 | v_time TIMESTAMP; 37 | v_row_ct BIGINT; 38 | v_is_correct_column_type BOOLEAN; 39 | v_constraint_name TEXT; 40 | 41 | BEGIN 42 | -- Get the partitioning column type 43 | EXECUTE format($sel$ 44 | SELECT 45 | LOWER(col.column_name), 46 | t.typname 47 | FROM 48 | (SELECT 49 | partrelid, 50 | unnest(partattrs) column_index 51 | FROM 52 | pg_partitioned_table) pt 53 | JOIN pg_class c on c.oid = pt.partrelid 54 | JOIN information_schema.columns col ON 55 | col.table_schema = c.relnamespace::regnamespace::text 56 | AND col.table_name = c.relname 57 | AND ordinal_position = pt.column_index 58 | JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid AND a.attname = col.column_name 59 | JOIN pg_catalog.pg_type t ON t.oid = a.atttypid 60 | WHERE 61 | c.relname = '%I' 62 | and relnamespace::regnamespace::text='%I' 63 | $sel$, v_relname, v_schema) 64 | INTO v_partition_column_name, v_coltype; 65 | 66 | -- We only create date constraints on tables partitioned on an integer 67 | IF NOT (v_coltype ~ 'int') OR (v_coltype IS NULL) THEN 68 | RAISE EXCEPTION 'Table %.% is not partitioned on an integer column type', v_schema, v_relname; 69 | END IF; 70 | 71 | -- The column for the constraint must be of type timestamp or date 72 | EXECUTE FORMAT( $sql$ 73 | SELECT data_type ~ 'timestamp' OR data_type ~ 'date' 74 | FROM information_schema.columns 75 | WHERE 76 | table_name = '%I' 77 | AND table_schema = '%I' 78 | AND column_name = '%s' 79 | $sql$, v_relname, v_schema, v_column_name) 80 | INTO v_is_correct_column_type; 81 | 82 | IF (NOT v_is_correct_column_type) OR (v_is_correct_column_type IS NULL) THEN 83 | RAISE EXCEPTION 'Column % of table %.% is not a date or a timestamp', v_column_name, v_schema, v_relname; 84 | END IF; 85 | 86 | -- Loop over all children 87 | FOR v_child IN 88 | SELECT 89 | child.relname, 90 | (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), v_boundary_regex))[2]::bigint as upper 91 | FROM pg_inherits 92 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 93 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 94 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 95 | WHERE 96 | LOWER(nmsp_child.nspname)=LOWER(v_schema) 97 | AND LOWER(parent.relname)=LOWER(v_relname) 98 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 99 | AND child.relname !~ 'mammoth' 100 | LOOP 101 | 102 | -- If child has at least one row we need to have a min constraint 103 | EXECUTE FORMAT( $sql$ SELECT 1 FROM %I.%I limit 1 $sql$, v_schema, v_child.relname); 104 | GET DIAGNOSTICS v_row_ct = ROW_COUNT; 105 | 106 | IF v_row_ct >= 1 THEN 107 | -- Construct constraint name 108 | v_constraint_name := concat(v_child.relname, '_', v_marker, '_min'); 109 | 110 | -- Check if min constraint already exists 111 | PERFORM 1 112 | FROM pg_catalog.pg_constraint c 113 | JOIN pg_class t ON t.oid = c.conrelid 114 | WHERE 115 | t.relname = v_child.relname 116 | AND t.relnamespace = v_schema::regnamespace 117 | AND c.contype = 'c' 118 | AND c.conname = v_constraint_name; 119 | 120 | IF NOT FOUND THEN 121 | -- Create constraint 122 | RAISE NOTICE 'Create new min constraint for partition %.%', v_schema, v_child.relname; 123 | 124 | -- select minimal value 125 | EXECUTE FORMAT($sql$ SELECT MIN(%s) FROM %I.%I $sql$, v_column_name, v_schema, v_child.relname) 126 | INTO v_time; 127 | 128 | -- Create the constraint 129 | EXECUTE format($sql$ ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%s >= '%s') NOT VALID 130 | $sql$, v_schema, v_child.relname, v_constraint_name, v_column_name, v_time); 131 | 132 | -- Mark constraint as validated in the catalog. This is within one transaction; save to do 133 | EXECUTE format($sql$ 134 | UPDATE pg_constraint pgc 135 | SET convalidated = true 136 | FROM pg_class c 137 | WHERE 138 | c.oid = pgc.conrelid 139 | AND connamespace = '%I'::regnamespace::oid 140 | AND c.relname = '%I' 141 | AND conname = '%s' 142 | $sql$, v_schema, v_child.relname, v_constraint_name); 143 | 144 | END IF; 145 | END IF; 146 | 147 | -- Check if child partition is full: A record matching upper boundary (exclusive) of the partition exists 148 | EXECUTE format($sql$ 149 | SELECT (MAX(%s)) = (SELECT %s - 1) FROM %I.%I 150 | $sql$,v_partition_column_name, v_child.upper, v_schema, v_child.relname) 151 | INTO v_partition_is_full; 152 | 153 | IF v_partition_is_full THEN 154 | -- Construct constraint name 155 | v_constraint_name := concat(v_child.relname, '_', v_marker, '_max'); 156 | 157 | -- Check if max constraint already exists 158 | PERFORM 1 159 | FROM pg_catalog.pg_constraint c 160 | JOIN pg_class t ON t.oid = c.conrelid 161 | WHERE 162 | t.relname = v_child.relname 163 | AND t.relnamespace = v_schema::regnamespace 164 | AND c.contype = 'c' 165 | AND c.conname = v_constraint_name; 166 | 167 | IF NOT FOUND THEN 168 | -- Create constraint 169 | RAISE NOTICE 'Create new max constraint for partition %.%', v_schema, v_child.relname; 170 | 171 | -- max value for data/timestamp column 172 | EXECUTE FORMAT($sql$ 173 | SELECT MAX(%s) FROM %I.%I 174 | $sql$, v_column_name, v_schema, v_child.relname) 175 | INTO v_time; 176 | 177 | -- Add the constraint 178 | EXECUTE format($sql$ 179 | ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%s <= '%s') NOT VALID 180 | $sql$, v_schema, v_child.relname, v_constraint_name, v_column_name, v_time); 181 | 182 | -- Mark constraint as validated in the catalog. This is within one transaction; save to do 183 | EXECUTE format($sql$ 184 | UPDATE pg_constraint pgc 185 | SET convalidated = true 186 | FROM pg_class c 187 | WHERE 188 | c.oid = pgc.conrelid 189 | AND connamespace = '%I'::regnamespace::oid 190 | AND c.relname = '%I' 191 | AND conname = '%s' 192 | $sql$, v_schema, v_child.relname, v_constraint_name); 193 | END IF; 194 | END IF; 195 | END LOOP; 196 | END 197 | $func$; 198 | -------------------------------------------------------------------------------- /sql/functions/partition_inheritance.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Converting traditional/normal table to a partitioned table with inheritance. 3 | The function will rename original table to $TABLE_mammoth, create an empty table 4 | called $TABLE and put it as a parent, create another child $TABLE_$v_endkey$v_interval 5 | and another one $TABLE_overflow. E.g.: 6 | 7 | From: test_partition 8 | to: 9 | - test_partition (parent table) 10 | - test_partition_mammoth 11 | - test_partition_overflow 12 | - test_partition_20230101_20230201 13 | 14 | PARAMETER TYPE DESCRIPTION 15 | v_schema TEXT schema location for the table 16 | v_tablename TEXT the normal table name 17 | v_keycolumn TEXT column name which the table will be partitioned based on 18 | v_startkey TEXT starting value for the the column in the original table; 19 | supports date & timestamp(tz) in YYYY-MM-DD format, and integers 20 | v_endkey TEXT end value for the column of the original table 21 | v_interval TEXT length for the new partition table, e.g.: 1 month, 1 week, 1000000000, and so on 22 | 23 | Example: 24 | SELECT dba.partition_inheritance('public','test_partition','creation_date','2000-01-01','2023-01-01','1 month'); 25 | SELECT dba.partition_inheritance('public','test_partition','id','1','70000000000','1000000000'); 26 | 27 | Caveats: 28 | Index names from the original $TABLE are not carried to any new tables, instead the names will follow postgres design 29 | e.g.: $TABLE_col1_col2_col2_idx and so on 30 | 31 | Limitations: 32 | Due to the complexity of table references, this function will not work if other tables are referencing to it. 33 | On the other hand, foreign keys on the table will be copied over to the new tables just fine. 34 | */ 35 | 36 | CREATE OR REPLACE FUNCTION dba.partition_inheritance(v_schemaname TEXT, v_tablename TEXT, v_keycolumn TEXT, v_startkey TEXT, v_endkey TEXT, v_interval TEXT) 37 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 38 | 39 | DECLARE 40 | v_suffix TEXT := 'mammoth'; 41 | v_options TEXT; 42 | v_referenced RECORD; 43 | v_partitionname TEXT; 44 | v_coltype TEXT; 45 | v_newend TEXT; 46 | v_newstart TEXT; 47 | 48 | BEGIN 49 | SELECT LOWER(typname::text) AS type INTO v_coltype 50 | FROM pg_catalog.pg_type t 51 | JOIN pg_catalog.pg_attribute a ON t.oid = a.atttypid 52 | JOIN pg_catalog.pg_class c ON a.attrelid = c.oid 53 | JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid 54 | WHERE n.nspname = LOWER(v_schemaname::name) 55 | AND c.relname = LOWER(v_tablename::name) 56 | AND a.attname = LOWER(v_keycolumn::name); 57 | 58 | IF v_coltype ~ 'timestamp' THEN 59 | IF v_startkey SIMILAR TO '[0-9][0-9][0-9][0-9]\-[0-9][0-9]\-[0-9][0-9]' THEN 60 | v_startkey := v_startkey || ' 00:00:00'; 61 | ELSE 62 | v_startkey := v_startkey; 63 | END IF; 64 | IF v_endkey SIMILAR TO '[0-9][0-9][0-9][0-9]\-[0-9][0-9]\-[0-9][0-9]' THEN 65 | v_endkey := v_endkey || ' 23:59:59.999999'; 66 | v_newstart := v_endkey::date + 1; 67 | ELSE 68 | v_endkey := v_endkey; 69 | v_newstart := v_endkey::timestamp + '00:00:00.000001'; 70 | END IF; 71 | EXECUTE format($sel$SELECT (%L::%I + %L::INTERVAL - '1 day'::INTERVAL)$sel$, v_newstart::date || ' 23:59:59.999999'::TEXT, v_coltype, v_interval) INTO v_newend; 72 | ELSE 73 | IF v_coltype ~ 'int' THEN 74 | EXECUTE format($sel$SELECT %I(%L::%I + 1)$sel$, v_coltype, v_endkey, v_coltype) INTO v_newstart; 75 | EXECUTE format($sel$SELECT %I(%L::%I + %L - 1)$sel$, v_coltype, v_newstart, v_coltype, v_interval) INTO v_newend; 76 | ELSIF v_coltype = 'date' THEN 77 | EXECUTE format($sel$SELECT %I(%L::%I + 1)$sel$, v_coltype, v_endkey, v_coltype) INTO v_newstart; 78 | EXECUTE format($sel$SELECT %I(%L::%I + %L::INTERVAL - '1 day'::INTERVAL)$sel$, v_coltype, v_newstart, v_coltype, v_interval) INTO v_newend; 79 | ELSE 80 | RAISE EXCEPTION 'Data type % IS NOT SUPPORTED.', v_coltype USING ERRCODE='ADYEN'; 81 | END IF; 82 | END IF; 83 | 84 | RAISE DEBUG 'Finding constraint from other tables connected to %', v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 85 | SELECT n.nspname || '.' || conrelid::regclass 86 | INTO v_referenced 87 | FROM pg_constraint c 88 | JOIN pg_namespace n ON n.oid = c.connamespace 89 | WHERE contype = 'f' AND n.nspname = LOWER(v_schemaname) 90 | AND conname IN (SELECT constraint_name FROM information_schema.constraint_table_usage WHERE table_schema = LOWER(v_schemaname) AND table_name = LOWER(v_tablename)); 91 | IF v_referenced IS NOT NULL THEN 92 | RAISE EXCEPTION 'FAILING: table % is being referenced by other tables, partitioning using inheritance IS NOT possible', v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 93 | END IF; 94 | 95 | v_partitionname := replace(regexp_replace(v_newstart::TEXT, '\ .*', ''), '-', '') || '_' || replace(regexp_replace(v_newend::TEXT, '\ .*', ''), '-', ''); 96 | RAISE DEBUG 'Beginning value: %, new partition value start: % and end: %, column type: %, interval: %, partition name: %', 97 | v_startkey, v_newstart, v_newend, v_coltype, v_interval, v_partitionname USING ERRCODE='ADYEN'; 98 | 99 | RAISE DEBUG 'original table name: %, new table name: %', v_schemaname || '.' || v_tablename, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 100 | EXECUTE format('ALTER TABLE %I.%I RENAME TO %I_%I', v_schemaname, v_tablename, v_tablename, v_suffix); 101 | 102 | RAISE DEBUG 'Creating new table % based on %', v_schemaname || '.' || v_tablename, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 103 | EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I_%I INCLUDING ALL)', 104 | v_schemaname, v_tablename, v_schemaname, v_tablename, v_suffix 105 | ); 106 | 107 | RAISE DEBUG 'Copying FK % based on %', v_schemaname || '.' || v_tablename, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 108 | PERFORM dba.partition_copy_fk_to_new_table(v_schemaname, v_tablename || '_' || v_suffix, v_tablename); 109 | 110 | SELECT btrim(reloptions::text,'{}') 111 | INTO v_options 112 | FROM pg_class AS c 113 | JOIN pg_namespace AS ns ON c.relnamespace=ns.oid 114 | WHERE relname = LOWER(v_tablename || '_' || v_suffix); 115 | IF v_options IS NOT NULL THEN 116 | RAISE DEBUG 'Setting table options: %', v_options USING ERRCODE='ADYEN'; 117 | EXECUTE format('ALTER TABLE ' || v_schemaname || '.' || v_tablename || ' SET (' || v_options || ');'); 118 | END IF; 119 | 120 | RAISE DEBUG 'Putting % as a child of %.', v_schemaname || '.' || v_tablename || '_' || v_suffix, v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 121 | EXECUTE format('ALTER TABLE %I.%I_%I INHERIT %I.%I', 122 | v_schemaname, v_tablename, v_suffix, v_schemaname, v_tablename); 123 | 124 | RAISE DEBUG 'Adding CHECK constraint on % called %_check, for % BETWEEN % AND %', 125 | v_schemaname || '.' || v_tablename || '_' || v_suffix, v_tablename || '_' || v_suffix, v_keycolumn, v_startkey, v_endkey USING ERRCODE='ADYEN'; 126 | EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I_%I_check CHECK (%I BETWEEN %L AND %L) NOT VALID', 127 | v_schemaname, v_tablename || '_' || v_suffix, v_tablename, v_suffix, v_keycolumn, v_startkey, v_endkey); 128 | 129 | RAISE DEBUG 'Setting the % CHECK as VALID', v_tablename || '_'|| v_suffix || '_check' USING ERRCODE='ADYEN'; 130 | EXECUTE FORMAT('UPDATE pg_constraint AS c SET convalidated=true FROM pg_namespace n WHERE c.connamespace=n.oid AND conname=%L AND nspname=%L', 131 | v_tablename || '_' || v_suffix || '_check', v_schemaname); 132 | 133 | PERFORM dba.partition_create_table_inherits_from_template(v_schemaname, v_tablename, v_partitionname), 134 | dba.partition_copy_indexes_to_new_table(v_schemaname, v_tablename, v_tablename || '_' || v_partitionname), 135 | dba.partition_copy_fk_to_new_table(v_schemaname, v_tablename, v_tablename || '_' || v_partitionname); 136 | 137 | RAISE DEBUG 'Adding CHECK constraint on % called %_check, for % BETWEEN % AND %', 138 | v_schemaname || '.' || v_tablename || '_' || v_partitionname, v_tablename || '_' || v_partitionname, v_keycolumn, v_newstart, v_newend USING ERRCODE='ADYEN'; 139 | EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I_check CHECK (%I BETWEEN %L AND %L)', 140 | v_schemaname, v_tablename || '_' || v_partitionname, v_tablename || '_' || v_partitionname, v_keycolumn, v_newstart, v_newend); 141 | 142 | RAISE DEBUG 'Creating overflow table % based on %', v_schemaname || '.' || v_tablename || '_overflow', v_tablename USING ERRCODE='ADYEN'; 143 | EXECUTE format( 144 | 'CREATE TABLE %I.%I (LIKE %I.%I INCLUDING ALL)', 145 | v_schemaname, v_tablename || '_overflow', v_schemaname, v_tablename 146 | ); 147 | 148 | RAISE DEBUG 'Putting % as a child of %', v_schemaname || '.' || v_tablename || '_overflow', v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 149 | EXECUTE format('ALTER TABLE %I.%I INHERIT %I.%I', 150 | v_schemaname, v_tablename || '_overflow', v_schemaname, v_tablename); 151 | 152 | PERFORM dba.partition_copy_fk_to_new_table(v_schemaname, v_tablename, v_tablename || '_overflow'); 153 | 154 | RETURN TRUE; 155 | 156 | END 157 | $func$; 158 | -------------------------------------------------------------------------------- /sql/functions/partition_calculate_free_partitions.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function calculates the number of unused partitions for a partitioned table. When the table has partitions in 3 | multiple ranges, the minimal number of unused partitions over all the ranges is returned. If the identifier for a range 4 | is provided, the number of unused partitions for this range is returned. 5 | 6 | When the table is partitioned based on a date or timestamp the function calculates the amount of partitions 7 | where the starting date/timestamp of the partition is larger than the current date. 8 | 9 | When the table is partitioned based on an integer the function calculates the amount of partitions 10 | where the lower boundary of the partition is larger than the current maximum value from the table. 11 | 12 | When the table is partitioned based on any other column type the function will return an error. 13 | 14 | PARAMETER TYPE DESCRIPTION 15 | v_schema TEXT schema location for the table 16 | v_relname TEXT the normal table name 17 | v_column_name TEXT the column name of the partitioned column 18 | v_coltype TEXT the type of the partitioned column 19 | v_range_identifier TEXT the identifier for the range. This must be an 'r' followed by a number. 20 | 21 | Example: 22 | SELECT dba.partition_calculate_free_partitions('public','partitioned_table'); 23 | SELECT dba.partition_calculate_free_partitions('public','partitioned_table', 'column_name', 'column_type'); 24 | SELECT dba.partition_calculate_free_partitions('public','partitioned_table', 'column_name', 'column_type', 'r1'); 25 | */ 26 | 27 | CREATE OR REPLACE FUNCTION dba.partition_calculate_free_partitions(v_schema TEXT, v_relname TEXT, v_column_name TEXT DEFAULT NULL, v_coltype TEXT DEFAULT NULL, v_range_identifier TEXT DEFAULT NULL) 28 | RETURNS INT LANGUAGE plpgsql AS $func$ 29 | 30 | DECLARE 31 | v_additional_partitions INT; 32 | v_is_partitioned BOOLEAN; 33 | v_boundary_regex CONSTANT TEXT := '.*\(\''?(.*?)\''?\).*\(\''?(.*?)\''?\).*'; 34 | v_is_range BOOLEAN; 35 | v_range TEXT; 36 | v_range_count INT; 37 | 38 | BEGIN 39 | -- Do a check if the table is actually partitioned 40 | EXECUTE format($sel$ 41 | SELECT count(*) > 0 42 | FROM pg_partitioned_table pt 43 | JOIN pg_class par on par.oid = pt.partrelid 44 | WHERE 45 | relnamespace::regnamespace::text = '%I' 46 | AND par.relname = '%I' 47 | $sel$, v_schema, v_relname) 48 | INTO v_is_partitioned; 49 | 50 | IF NOT v_is_partitioned THEN 51 | RAISE EXCEPTION 'Table % is not a partitioned table.', v_schema || '.' || v_relname USING ERRCODE='ADYEN'; 52 | END IF; 53 | 54 | IF v_coltype IS NULL OR v_column_name IS NULL THEN 55 | EXECUTE format($sel$ 56 | SELECT 57 | LOWER(col.column_name), 58 | t.typname 59 | FROM 60 | (SELECT 61 | partrelid, 62 | unnest(partattrs) column_index 63 | FROM 64 | pg_partitioned_table) pt 65 | JOIN pg_class c on c.oid = pt.partrelid 66 | JOIN information_schema.columns col ON 67 | col.table_schema = c.relnamespace::regnamespace::text 68 | AND col.table_name = c.relname 69 | AND ordinal_position = pt.column_index 70 | JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid AND a.attname = col.column_name 71 | JOIN pg_catalog.pg_type t ON t.oid = a.atttypid 72 | WHERE 73 | LOWER(c.relname) = LOWER('%I') 74 | and LOWER(relnamespace::regnamespace::text) = LOWER('%I') 75 | $sel$, v_relname, v_schema) 76 | INTO v_column_name, v_coltype; 77 | END IF; 78 | 79 | -- It is a range when the v_range_identifier is NOT NULL and not empty string 80 | v_is_range := (v_range_identifier <> '') IS TRUE; 81 | 82 | IF v_is_range AND NOT v_coltype ~ 'int' THEN 83 | RAISE EXCEPTION 'Table % has multiple ranges, but is the partition column is not a integer', v_schema || '.' || v_relname USING ERRCODE='ADYEN'; 84 | END IF; 85 | 86 | -- If the table has multiple ranges, we calculate the number of free partitions per range and return the smallest number. 87 | -- When the table is not partitioned over multiple ranges this block is skipped. 88 | <> 89 | BEGIN 90 | -- We only check for multiple ranges if no range_identifier is provided. 91 | IF NOT v_is_range THEN 92 | -- We can have multiple ranges, or the table is not partitioned in multiple ranges 93 | FOR v_range IN 94 | EXECUTE format($sel$ 95 | SELECT (regexp_match(child.relname, '%I_(r\d+)_.*'))[1] 96 | FROM pg_partitioned_table pt 97 | JOIN pg_class parent on pt.partrelid = parent.oid 98 | JOIN pg_inherits i on pt.partrelid = i.inhparent 99 | JOIN pg_class child on i.inhrelid = child.oid 100 | WHERE parent.relname = '%I' 101 | AND parent.relnamespace::regnamespace::text='%I' 102 | GROUP by (regexp_match(child.relname, '%I_(r\d+)_.*'))[1] 103 | $sel$, v_relname, v_relname, v_schema, v_relname) 104 | 105 | LOOP 106 | 107 | -- If v_range is empty, the table is not partitioned in multiple ranges. Exit this block and continue the default calculation. 108 | EXIT range_block WHEN v_range IS NULL; 109 | 110 | -- Recursively calculate the number of free partitions per range 111 | EXECUTE format($sel$ select dba.partition_calculate_free_partitions('%I', '%I', '%I', '%I', %L) $sel$, v_schema, v_relname, v_column_name, v_coltype, v_range) INTO v_range_count; 112 | 113 | -- We keep the result if this is the first range we calculated, or if the result is smaller than the current value. 114 | IF v_additional_partitions IS NULL OR v_range_count < v_additional_partitions THEN 115 | v_additional_partitions := v_range_count; 116 | END IF; 117 | 118 | END LOOP; 119 | 120 | -- Return the smallest value for all partitions. 121 | RETURN v_additional_partitions; 122 | END IF; 123 | END range_block; 124 | 125 | -- At this point we can be in one of two situations 126 | -- - The table is not partitioned into multiple ranges 127 | -- - We are calculating the number of free partitions for a given range 128 | 129 | -- The calculation is equal for both situations. Lets calculate. 130 | CASE 131 | WHEN v_coltype ~ 'int' THEN 132 | -- Count the number of unused partitions 133 | -- An unused partition must have a higher lower boundary than the current maximum value in the partition column 134 | 135 | EXECUTE format($sel$ 136 | -- The boundaries of the latest available partition 137 | with partitions as ( 138 | SELECT 139 | (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), %L))[1]::bigint as lower, 140 | (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), %L))[2]::bigint as upper 141 | FROM pg_inherits 142 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 143 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 144 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 145 | WHERE 146 | LOWER(nmsp_child.nspname)=LOWER('%I') 147 | AND LOWER(parent.relname)=LOWER('%I') 148 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 149 | AND (NOT '%I' or child.relname like '%I_' || %L || '_%%') 150 | ORDER BY 1 151 | ) 152 | select count(*) from partitions where lower > (select coalesce(max(%I),0) from %s where %I < (select max(upper) from partitions)) 153 | $sel$, 154 | v_boundary_regex, v_boundary_regex, v_schema, v_relname, v_is_range, v_relname, v_range_identifier, 155 | v_column_name, v_schema || '.' || v_relname, v_column_name 156 | ) 157 | INTO v_additional_partitions; 158 | 159 | WHEN v_coltype ~ 'date' OR v_coltype ~ 'timestamp' THEN 160 | -- Count the number of partitions starting after today 161 | EXECUTE format($sel$ 162 | SELECT 163 | count(*) 164 | FROM pg_inherits 165 | JOIN pg_class parent ON pg_inherits.inhparent = parent.oid 166 | JOIN pg_class child ON pg_inherits.inhrelid = child.oid 167 | JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace 168 | WHERE 169 | LOWER(nmsp_child.nspname)=LOWER('%I') 170 | AND LOWER(parent.relname)=LOWER('%I') 171 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 172 | AND (regexp_match(pg_catalog.pg_get_expr(child.relpartbound, child.oid), %L))[1]::date > current_date 173 | $sel$, v_schema, v_relname, v_boundary_regex) 174 | INTO v_additional_partitions; 175 | ELSE 176 | RAISE EXCEPTION 'Data type % IS NOT SUPPORTED.', v_coltype USING ERRCODE='ADYEN'; 177 | END CASE; 178 | 179 | RETURN v_additional_partitions; 180 | END 181 | $func$; 182 | -------------------------------------------------------------------------------- /sql/functions/partition_add_up_to_nr_of_free_partitions.sql: -------------------------------------------------------------------------------- 1 | /* 2 | This function creates new partitions for all native partitioned tables in the database untill there are at least 3 | number_of_additional_partitions available, unused partitions. When the number of requested, free partitions already 4 | exits the function does nothing. 5 | 6 | When the table is partitioned based on a date or timestamp the function will create new partitions untill there are 7 | number_of_additional_partitions partitions where the starting date/timestamp of the partition is larger than the current date. 8 | 9 | When the table is partitioned based on an integer the function will create new partitions untill there are number_of_additional_partitions 10 | partitions where the lower boundary of the partition is larger than the current maximum value from the table. 11 | 12 | When the table is partitioned based on any other column type the function will return an error. 13 | 14 | PARAMETER TYPE DESCRIPTION 15 | v_schema TEXT schema location for the table 16 | v_relname TEXT the normal table name 17 | v_number_of_additional_partitions TEXT the number of additional, unused partitions 18 | 19 | Example: 20 | SELECT dba.partition_add_up_to_nr_of_free_partitions('public','test_partition', 3); 21 | */ 22 | 23 | CREATE OR REPLACE FUNCTION dba.partition_add_up_to_nr_of_free_partitions(v_schema TEXT, v_relname TEXT, v_number_of_additional_partitions INT) 24 | RETURNS BOOLEAN LANGUAGE plpgsql 25 | SECURITY DEFINER 26 | SET search_path = pg_catalog, pg_temp 27 | AS $func$ 28 | 29 | DECLARE 30 | v_is_partitioned BOOLEAN; 31 | v_column_name TEXT; 32 | v_lastrange TEXT ARRAY; 33 | v_lastrange_size TEXT; 34 | v_lastpartitionname TEXT; 35 | v_coltype TEXT; 36 | v_newstart TEXT; 37 | v_newend TEXT; 38 | v_partition_suffix TEXT; 39 | v_current_additional_partitions INT; 40 | v_range TEXT; 41 | v_is_range BOOLEAN; 42 | v_new_partition_name TEXT; 43 | v_table_owner NAME; 44 | v_reloptions TEXT; 45 | V_ATTACH_LOCK_TIMEOUT CONSTANT INT := 1000 ; -- ms 46 | V_ATTACH_RETRIES CONSTANT INT := 3; 47 | V_ATTACH_RETRY_SLEEP CONSTANT INT := 10; -- seconds 48 | 49 | BEGIN 50 | -- Set the statement timeout. We don't want to block the application for too long. We need a lock to retrieve partition 51 | -- details and for attaching the partition. 52 | EXECUTE FORMAT('SET local lock_timeout TO %L', V_ATTACH_LOCK_TIMEOUT); 53 | 54 | v_schema:=LOWER(v_schema); 55 | v_relname:=LOWER(v_relname); 56 | 57 | RAISE DEBUG 'Checking number of free available partitions for table %', v_relname USING ERRCODE='ADYEN'; 58 | 59 | -- Do a check if the table is actually partitioned 60 | EXECUTE format($sel$ 61 | SELECT count(*) > 0 62 | FROM pg_partitioned_table pt 63 | JOIN pg_class par on par.oid = pt.partrelid 64 | WHERE 65 | LOWER(relnamespace::regnamespace::text) = LOWER('%I') 66 | AND LOWER(par.relname) = LOWER('%I') 67 | $sel$, v_schema, v_relname) 68 | INTO v_is_partitioned; 69 | 70 | IF NOT v_is_partitioned THEN 71 | RAISE EXCEPTION 'Table % is not a partitioned table.', v_schema || '.' || v_relname USING ERRCODE='ADYEN'; 72 | END IF; 73 | 74 | -- Determine the name and type of the column used for partitioning 75 | EXECUTE format($sel$ 76 | SELECT 77 | LOWER(col.column_name), 78 | t.typname 79 | FROM 80 | (SELECT 81 | partrelid, 82 | unnest(partattrs) column_index 83 | FROM 84 | pg_partitioned_table) pt 85 | JOIN pg_class c on c.oid = pt.partrelid 86 | JOIN information_schema.columns col ON 87 | col.table_schema = c.relnamespace::regnamespace::text 88 | AND col.table_name = c.relname 89 | AND ordinal_position = pt.column_index 90 | JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid AND a.attname = col.column_name 91 | JOIN pg_catalog.pg_type t ON t.oid = a.atttypid 92 | WHERE 93 | c.relname = '%I' 94 | and relnamespace::regnamespace::text='%I' 95 | $sel$, v_relname, v_schema) 96 | INTO v_column_name, v_coltype; 97 | 98 | RAISE DEBUG 'Table % is partitioned on column % of type %', v_relname, v_column_name, v_coltype USING ERRCODE='ADYEN'; 99 | 100 | -- A table might have multiple ranges with partitions. We need to create new partitions for every range. 101 | -- When the table does not have multiple ranges, we only consider the single set of partitions. 102 | FOR v_range IN 103 | EXECUTE format($sel$ 104 | SELECT (regexp_match(child.relname, '%I_(r\d+)_.*'))[1] 105 | FROM pg_partitioned_table pt 106 | JOIN pg_class parent on pt.partrelid = parent.oid 107 | JOIN pg_inherits i on pt.partrelid = i.inhparent 108 | JOIN pg_class child on i.inhrelid = child.oid 109 | WHERE parent.relname = '%I' 110 | AND parent.relnamespace::regnamespace::text='%I' 111 | AND pg_catalog.pg_get_expr(child.relpartbound, child.oid) <> 'DEFAULT' 112 | GROUP by (regexp_match(child.relname, '%I_(r\d+)_.*'))[1] 113 | $sel$, v_relname, v_relname, v_schema, v_relname) 114 | 115 | LOOP 116 | v_is_range := v_range IS NOT NULL; 117 | 118 | RAISE DEBUG 'is range: %', v_is_range; 119 | RAISE DEBUG 'current range: %', v_range; 120 | 121 | -- Calculate the number of free partitions for this table 122 | EXECUTE format($sel$ select dba.partition_calculate_free_partitions('%I', '%I', '%I', '%I', %L) $sel$, v_schema, v_relname, v_column_name, v_coltype, v_range) INTO v_current_additional_partitions; 123 | 124 | RAISE DEBUG 'Number of additional partitions: %', v_current_additional_partitions USING ERRCODE='ADYEN'; 125 | 126 | -- Check if we already have the requested number of free additional partitions 127 | IF v_current_additional_partitions >= v_number_of_additional_partitions THEN 128 | -- Nothing to do, continue to the next range 129 | CONTINUE; 130 | END IF; 131 | 132 | -- We need to create at least one partition 133 | 134 | -- Create new partitions for the table until number of desired partitions has been reached 135 | WHILE v_current_additional_partitions < v_number_of_additional_partitions 136 | LOOP 137 | -- Determine boundaries for the latest existing partition 138 | EXECUTE FORMAT($sel$ 139 | SELECT v_childrelname, v_range FROM dba.partition_get_last_partition_details('%I', '%I', %L) 140 | $sel$, v_schema, v_relname, v_range ) 141 | INTO v_lastpartitionname, v_lastrange; 142 | 143 | RAISE DEBUG 'schema %', v_schema USING ERRCODE='ADYEN'; 144 | RAISE DEBUG 'Last partition %', v_lastpartitionname USING ERRCODE='ADYEN'; 145 | RAISE DEBUG 'Last lower bound %', v_lastrange[1] USING ERRCODE='ADYEN'; 146 | RAISE DEBUG 'Last upper bound %', v_lastrange[2] USING ERRCODE='ADYEN'; 147 | 148 | CASE 149 | WHEN v_coltype ~ 'int' THEN 150 | -- Calculate the range based on latest boundaries 151 | SELECT v_lastrange[2]::bigint - v_lastrange[1]::bigint INTO v_lastrange_size; 152 | RAISE DEBUG 'Last range size %', v_lastrange_size USING ERRCODE='ADYEN'; 153 | 154 | -- Calculate boundaries for the new partition 155 | SELECT v_lastrange[2] INTO v_newstart; 156 | SELECT v_lastrange[2]::bigint + v_lastrange_size::bigint INTO v_newend; 157 | 158 | WHEN v_coltype ~ 'date' THEN 159 | -- Calculate the range based on latest boundaries 160 | SELECT age(v_lastrange[2]::date, v_lastrange[1]::date) INTO v_lastrange_size; 161 | RAISE DEBUG 'Last range size %', v_lastrange_size USING ERRCODE='ADYEN'; 162 | 163 | -- Calculate boundaries for the new partition 164 | SELECT v_lastrange[2] INTO v_newstart; 165 | SELECT v_lastrange[2]::date + v_lastrange_size::interval INTO v_newend; 166 | WHEN v_coltype ~ 'timestamp' THEN 167 | -- Calculate the range based on latest boundaries 168 | SELECT age(v_lastrange[2]::date, v_lastrange[1]::date) INTO v_lastrange_size; 169 | RAISE DEBUG 'Last range size %', v_lastrange_size USING ERRCODE='ADYEN'; 170 | 171 | -- Calculate boundaries for the new partition 172 | SELECT v_lastrange[2] INTO v_newstart; 173 | SELECT v_lastrange[2]::timestamp + v_lastrange_size::interval INTO v_newend; 174 | ELSE 175 | RAISE EXCEPTION 'Data type % IS NOT SUPPORTED.', v_coltype USING ERRCODE='ADYEN'; 176 | END CASE; 177 | 178 | RAISE DEBUG 'New lower bound %', v_newstart USING ERRCODE='ADYEN'; 179 | RAISE DEBUG 'New upper bound %', v_newend USING ERRCODE='ADYEN'; 180 | 181 | -- Determine the suffix for the new partition in format _ 182 | v_partition_suffix := replace(regexp_replace(v_newstart::TEXT, '\ .*', ''), '-', '') || '_' || replace(regexp_replace(v_newend::TEXT, '\ .*', ''), '-', ''); 183 | 184 | RAISE DEBUG 'New partition suffix %', v_partition_suffix USING ERRCODE='ADYEN'; 185 | 186 | -- Create the new partition 187 | v_new_partition_name := REPLACE(CONCAT(v_relname, '_', v_range, '_', v_partition_suffix), '__', '_'); 188 | 189 | RAISE NOTICE 'Adding new partition % to table %', v_schema || '.' || v_new_partition_name, v_schema || '.' || v_relname; 190 | 191 | EXECUTE FORMAT('CREATE TABLE %I.%I (LIKE %I.%I INCLUDING ALL)', 192 | v_schema, v_new_partition_name, v_schema, v_lastpartitionname 193 | ); 194 | 195 | -- When the constraint on the to be attached partition doesn't overlap with the constraint on the possible 196 | -- available default partition we don't required an ACCESS EXCLUSIVE lock on the table. 197 | EXECUTE format('ALTER TABLE %I.%I add constraint partition_constraint check ((%I IS NOT NULL) AND (%I >= %L::%I) AND (%I < %L::%I))', 198 | v_schema, v_new_partition_name, v_column_name, v_column_name, v_newstart, v_coltype, v_column_name, v_newend, v_coltype 199 | ); 200 | 201 | -- Copy the table storage parameters to the new partition 202 | EXECUTE FORMAT($sel$ 203 | SELECT array_to_string(reloptions, ',') 204 | FROM pg_class 205 | WHERE relname = '%I' and relnamespace::regnamespace::text='%I'; 206 | $sel$, v_lastpartitionname, v_schema) 207 | INTO v_reloptions; 208 | 209 | IF v_reloptions IS NOT NULL THEN 210 | EXECUTE FORMAT('ALTER TABLE %I.%I set (%s)', 211 | v_schema, v_new_partition_name, v_reloptions); 212 | END IF; 213 | 214 | -- Try to attach the new table to the parent. We need a AccessExclusiveLock when a default partition exists. We 215 | -- try to get a lock for V_ATTACH_LOCK_TIMEOUT ms. If we can't get the lock, we wait V_ATTACH_RETRY_SLEEP seconds 216 | -- and try again for a maximum of V_ATTACH_RETRIES times. If we didn't succeed in attaching the partition we drop the 217 | -- latest created table and exit the function with 'false'. 218 | FOR loop_cnt in 1..V_ATTACH_RETRIES LOOP 219 | BEGIN 220 | -- Add the new table as partition to the parent table 221 | EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)', 222 | v_schema, v_relname, v_schema, v_new_partition_name, v_newstart, v_newend); 223 | 224 | SELECT tableowner FROM pg_tables WHERE schemaname = v_schema AND tablename = v_relname 225 | INTO v_table_owner; 226 | 227 | EXECUTE FORMAT('ALTER TABLE %I.%I OWNER TO %I', 228 | v_schema, v_new_partition_name, v_table_owner); 229 | 230 | -- Drop the partition constraint. This constraint is now implicitly added by the database and the one 231 | -- we created is no longer required for any reason. 232 | EXECUTE format('ALTER TABLE %I.%I drop constraint partition_constraint', 233 | v_schema, v_new_partition_name); 234 | 235 | -- Attaching succeeded. Exit the loop. 236 | EXIT; 237 | 238 | EXCEPTION 239 | WHEN lock_not_available THEN 240 | RAISE NOTICE 'Lock not available %', loop_cnt; 241 | 242 | IF loop_cnt = V_ATTACH_RETRIES THEN 243 | RAISE NOTICE 'Attaching table failed'; 244 | 245 | -- Drop the newly created table and exit 246 | EXECUTE format('DROP TABLE %I.%I', v_schema, v_new_partition_name); 247 | 248 | RETURN FALSE; 249 | END IF; 250 | 251 | PERFORM PG_SLEEP(V_ATTACH_RETRY_SLEEP); 252 | END; 253 | END LOOP; 254 | 255 | -- Recalculate the amount of free partitions 256 | EXECUTE FORMAT($sel$ 257 | SELECT dba.partition_calculate_free_partitions('%I', '%I', '%I', '%I', %L) 258 | $sel$, v_schema, v_relname, v_column_name, v_coltype, v_range) 259 | INTO v_current_additional_partitions; 260 | END LOOP; 261 | END LOOP; 262 | 263 | RETURN TRUE; 264 | END 265 | $func$; 266 | -------------------------------------------------------------------------------- /sql/functions/partition_declarative.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Converting traditional/normal table to a partitioned table with declarative/native partitioning. 3 | Supporting partitioning ONLY by RANGE. 4 | 5 | Unlike dba.partition_inheritance function, where it will not work if the table is being 6 | referenced by other tables, native partitioning is working fine with it being referenced by others. 7 | 8 | The function will rename original table to $TABLE_mammoth, create an empty table 9 | called $TABLE and put it as main table and create another partition $TABLE_$v_endkey$v_interval E.g.: 10 | 11 | From: test_partition 12 | to: 13 | - test_partition (parent table) 14 | - test_partition_mammoth 15 | - test_partition_20220401_20220430 16 | - test_partition_template (if the column is not in PK/unique index) 17 | 18 | PARAMETER TYPE DESCRIPTION 19 | v_schema TEXT schema location for the table 20 | v_tablename TEXT the normal table name 21 | v_keycolumn TEXT column name which the table will be partitioned based on 22 | v_startkey TEXT starting value for the the column in the original table; 23 | supports date & timestamp(tz) in YYYY-MM-DD format, and integers 24 | v_endkey TEXT new value for the new partition *) 25 | v_interval TEXT length for the new partition table, e.g.: 1 month, 1 week, 1000000000, and so on 26 | v_nopk BOOLEAN set to true if the partition column is not in primary key or unique index; 27 | discouraged, unless application can ensure the data validity 28 | v_move_trg BOOLEAN set to true if you want to move triggers to newly partitioned table 29 | 30 | Example: 31 | SELECT dba.partition_native('public','test_partition','id','1','1000000','1000'); 32 | SELECT dba.partition_native('public','test_partition_date','creation_date','1970-01-01','2023-01-01','1 month',TRUE,TRUE); 33 | 34 | Caveats: 35 | Index names from the original $TABLE are not carried to any new tables, instead the names will follow 36 | postgres design, e.g.: $TABLE_col1_col2_col2_idx and so on 37 | 38 | WARNING: 39 | If the table is being referenced by other tables, YOU HAVE TO RUN validate constraint; we set them as not valid 40 | to make this function executed faster no matter the table size 41 | 42 | Notes: 43 | *) Postgres native partitioning where the last value is exclusive 44 | */ 45 | 46 | CREATE OR REPLACE FUNCTION dba.partition_native(v_schemaname TEXT, v_tablename TEXT, v_keycolumn TEXT, v_startkey TEXT, v_endkey TEXT, v_interval TEXT, v_nopk BOOLEAN DEFAULT FALSE, v_move_trg BOOLEAN DEFAULT FALSE) 47 | RETURNS BOOLEAN LANGUAGE plpgsql AS $func$ 48 | 49 | DECLARE 50 | v_suffix TEXT := 'mammoth'; 51 | v_references RECORD; 52 | v_rows RECORD; 53 | v_options TEXT; 54 | v_partitionname TEXT; 55 | v_coltype TEXT; 56 | v_newend TEXT; 57 | v_newstart TEXT; 58 | v_newindexname TEXT; 59 | v_statement TEXT; 60 | v_tablesource TEXT; 61 | 62 | BEGIN 63 | SELECT LOWER(typname::text) AS type INTO v_coltype 64 | FROM pg_catalog.pg_type t 65 | JOIN pg_catalog.pg_attribute a ON t.oid = a.atttypid 66 | JOIN pg_catalog.pg_class c ON a.attrelid = c.oid 67 | JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid 68 | WHERE n.nspname = LOWER(v_schemaname::name) 69 | AND c.relname = LOWER(v_tablename::name) 70 | AND a.attname = LOWER(v_keycolumn::name); 71 | 72 | IF v_nopk IS TRUE THEN 73 | v_tablesource := v_tablename || '_template'; 74 | ELSE 75 | v_tablesource := v_tablename || '_' || v_suffix; 76 | END IF; 77 | 78 | IF v_coltype ~ 'timestamp' THEN 79 | v_startkey := v_startkey || ' 00:00:00'; 80 | v_endkey := v_endkey::date + 1 || ' 00:00:00'; 81 | v_newstart := v_endkey; 82 | EXECUTE format($sel$SELECT (%L::%I + %L::INTERVAL)$sel$, v_newstart, v_coltype, v_interval) INTO v_newend; 83 | ELSE 84 | IF v_coltype ~ 'int' THEN 85 | EXECUTE format($sel$SELECT %I(%L::%I)$sel$, v_coltype, v_endkey, v_coltype) INTO v_newstart; 86 | EXECUTE format($sel$SELECT %I(%L::%I + %L)$sel$, v_coltype, v_newstart, v_coltype, v_interval) INTO v_newend; 87 | ELSIF v_coltype = 'date' THEN 88 | EXECUTE format($sel$SELECT %I(%L::%I)$sel$, v_coltype, v_endkey, v_coltype) INTO v_newstart; 89 | EXECUTE format($sel$SELECT %I(%L::%I + %L::INTERVAL)$sel$, v_coltype, v_newstart, v_coltype, v_interval) INTO v_newend; 90 | ELSE 91 | RAISE EXCEPTION 'Data type % IS NOT SUPPORTED.', v_coltype USING ERRCODE='ADYEN'; 92 | END IF; 93 | END IF; 94 | 95 | v_partitionname := replace(regexp_replace(v_newstart::TEXT, '\ .*', ''), '-', '') || '_' || replace(regexp_replace(v_newend::TEXT, '\ .*', ''), '-', ''); 96 | RAISE DEBUG 'Beginning value: %, new partition value start: % and end: %, column type: %, interval: %, partition name: %', 97 | v_startkey, v_newstart, v_newend, v_coltype, v_interval, v_partitionname USING ERRCODE='ADYEN'; 98 | 99 | IF v_move_trg IS TRUE THEN 100 | CREATE TEMP TABLE tmp_trgs AS 101 | SELECT tgname, pg_get_triggerdef(oid) triggerdef 102 | FROM pg_trigger 103 | WHERE tgrelid = (v_schemaname||'.'||v_tablename)::regclass AND tgtype = 21; 104 | 105 | FOR v_rows in 106 | SELECT tgname FROM tmp_trgs 107 | LOOP 108 | RAISE DEBUG 'Dropping trigger % on original table %', v_rows.tgname, v_schemaname||'.'||v_tablename USING ERRCODE='ADYEN'; 109 | EXECUTE format('DROP TRIGGER %I ON %I.%I', v_rows.tgname, v_schemaname, v_tablename); 110 | END LOOP; 111 | END IF; 112 | 113 | RAISE DEBUG 'original table name: %, new table name: %', v_schemaname || '.' || v_tablename, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 114 | EXECUTE format('ALTER TABLE %I.%I RENAME TO %I_%I', v_schemaname, v_tablename, v_tablename, v_suffix); 115 | 116 | RAISE DEBUG 'Renaming indexes ON %', v_schemaname ||'.'|| v_tablename || v_suffix USING ERRCODE='ADYEN'; 117 | 118 | FOR v_rows IN 119 | SELECT indexname FROM pg_indexes 120 | WHERE schemaname = LOWER(v_schemaname) 121 | AND tablename = LOWER(v_tablename||'_'||v_suffix) 122 | LOOP 123 | IF LOWER(v_rows.indexname) ~ LOWER(v_tablename) THEN 124 | v_newindexname := regexp_replace(v_rows.indexname, LOWER(v_tablename), LOWER(v_tablename||'_'||v_suffix)); 125 | IF length(v_newindexname) > 64 THEN 126 | v_newindexname := substring(LOWER(v_newindexname), 1, 57) || '_idx' || trunc(random() * 9 + 1); 127 | END IF; 128 | ELSE 129 | v_newindexname := substring(LOWER(v_tablename||'_'||v_suffix), 1, 57) || '_idx_' || trunc(random() * 9 + 1); 130 | END IF; 131 | RAISE DEBUG 'Renaming index from % to: %', v_rows.indexname, v_newindexname USING ERRCODE='ADYEN'; 132 | EXECUTE format('ALTER INDEX %I.%I RENAME TO %I', LOWER(v_schemaname), v_rows.indexname, v_newindexname); 133 | END LOOP; 134 | 135 | IF v_nopk IS TRUE THEN 136 | RAISE DEBUG 'Creating new template table % based on %', v_schemaname || '.' || v_tablesource, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 137 | EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I_%I INCLUDING ALL)', 138 | v_schemaname, v_tablesource, v_schemaname, v_tablename, v_suffix, v_keycolumn 139 | ); 140 | 141 | RAISE DEBUG 'Creating partitioned table % based on %', v_schemaname || '.' || v_tablename, v_tablesource USING ERRCODE='ADYEN'; 142 | EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I INCLUDING ALL EXCLUDING INDEXES) PARTITION BY RANGE (%I)', 143 | v_schemaname, v_tablename, v_schemaname, v_tablesource, v_keycolumn 144 | ); 145 | 146 | RAISE DEBUG 'Copying indexes FROM % TO %', v_schemaname ||'.'|| v_tablesource, v_schemaname ||'.'|| v_tablename USING ERRCODE='ADYEN'; 147 | FOR v_rows IN 148 | WITH indexes AS ( 149 | SELECT indexdef, indexname FROM pg_indexes 150 | WHERE schemaname = LOWER(v_schemaname) 151 | AND tablename = LOWER(v_tablesource) 152 | ) 153 | SELECT indexdef, indisprimary, indexname FROM indexes 154 | JOIN pg_class ON pg_class.relname = indexes.indexname 155 | JOIN pg_index ON pg_class.oid = pg_index.indexrelid 156 | JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace 157 | WHERE pg_namespace.nspname = LOWER(v_schemaname) 158 | LOOP 159 | IF v_rows.indisprimary IS FALSE THEN 160 | IF LOWER(v_rows.indexname) ~ LOWER(v_tablesource) THEN 161 | v_newindexname := regexp_replace(v_rows.indexname, LOWER(v_tablesource), LOWER(v_tablename)); 162 | IF length(v_newindexname) > 64 THEN 163 | v_newindexname := substring(LOWER(v_newindexname), 1, 57) || '_idx' || trunc(random() * 9 + 1); 164 | END IF; 165 | ELSE 166 | -- this is forced because we need table name in indexname 167 | -- otherwise it can cause further break down 168 | v_newindexname := substring(LOWER(v_tablename), 1, 57) || '_idx_' || trunc(random() * 9 + 1); 169 | END IF; 170 | v_statement := regexp_replace(v_rows.indexdef, LOWER(v_schemaname) || '.' || LOWER(v_tablesource), LOWER(v_schemaname) || '.' || LOWER(v_tablename)); 171 | v_statement := regexp_replace(v_statement, LOWER(v_rows.indexname), LOWER(v_newindexname)); 172 | RAISE DEBUG 'Creating an index using: %', v_statement USING ERRCODE='ADYEN'; 173 | EXECUTE format(v_statement); 174 | END IF; 175 | END LOOP; 176 | ELSE 177 | RAISE DEBUG 'Creating partitioned table % based on %', v_schemaname || '.' || v_tablename, v_tablesource USING ERRCODE='ADYEN'; 178 | EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I INCLUDING ALL) PARTITION BY RANGE (%I)', 179 | v_schemaname, v_tablename, v_schemaname, v_tablesource, v_keycolumn 180 | ); 181 | END IF; 182 | 183 | IF v_move_trg IS TRUE THEN 184 | FOR v_rows in 185 | SELECT triggerdef, tgname FROM tmp_trgs 186 | LOOP 187 | RAISE DEBUG 'Creating trigger % on new table %', v_rows.tgname, v_schemaname||'.'||v_tablename USING ERRCODE='ADYEN'; 188 | EXECUTE format(v_rows.triggerdef); 189 | END LOOP; 190 | END IF; 191 | 192 | RAISE DEBUG 'Copying FK % based on %', v_schemaname || '.' || v_tablename, v_tablename || '_' || v_suffix USING ERRCODE='ADYEN'; 193 | FOR v_references IN 194 | SELECT conname, pg_get_constraintdef(oid) as statement from pg_constraint where conrelid=(LOWER(v_schemaname || '.' || v_tablename || '_' || v_suffix))::regclass and contype='f' and conparentid = 0 195 | LOOP 196 | EXECUTE format('ALTER TABLE %s.%s ADD CONSTRAINT %s %s;', v_schemaname, v_tablename, 197 | regexp_replace(v_references.conname, LOWER(v_tablename || '_' || v_suffix), LOWER(v_tablename), 'g'), v_references.statement); 198 | END LOOP; 199 | 200 | RAISE DEBUG 'Finding constraint from other tables connected to %', v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 201 | CREATE TEMP TABLE tmp_fks AS 202 | SELECT n.nspname || '.' || cl.relname AS table_from, conname, pg_get_constraintdef(c.oid) AS condef, conrelid AS conn_table 203 | FROM pg_constraint c 204 | JOIN pg_class cl on c.conrelid = cl.oid 205 | JOIN pg_namespace n ON n.oid = c.connamespace 206 | WHERE contype = 'f' AND n.nspname = LOWER(v_schemaname) 207 | AND conname IN (SELECT constraint_name FROM information_schema.constraint_table_usage WHERE table_schema = LOWER(v_schemaname) AND table_name = LOWER(v_tablename || '_' || v_suffix)); 208 | 209 | FOR v_references IN 210 | SELECT table_from, condef, conname 211 | FROM tmp_fks 212 | LOOP 213 | RAISE DEBUG 'Dropping constraint % FROM % AND add it to the (new) parent table', v_references.conname, v_references.table_from USING ERRCODE='ADYEN'; 214 | v_references.condef := regexp_replace(v_references.condef, LOWER(v_tablename || '_' || v_suffix), LOWER(v_tablename)); 215 | EXECUTE format('ALTER TABLE %s DROP CONSTRAINT %I', v_references.table_from, v_references.conname); 216 | EXECUTE format('ALTER TABLE %s ADD CONSTRAINT %I %s NOT VALID', v_references.table_from, v_references.conname, v_references.condef); 217 | END LOOP; 218 | 219 | SELECT btrim(reloptions::text,'{}') 220 | INTO v_options 221 | FROM pg_class AS c 222 | JOIN pg_namespace AS ns ON c.relnamespace=ns.oid 223 | WHERE relname = LOWER(v_tablename || '_' || v_suffix); 224 | IF v_options IS NOT NULL THEN 225 | RAISE DEBUG 'Setting table options: %', v_options USING ERRCODE='ADYEN'; 226 | RAISE NOTICE 'XXXXXXXXX IMPORTANT XXXXXXXXX' USING ERRCODE='ADYEN'; 227 | RAISE NOTICE 'Run this command after you are done' USING ERRCODE='ADYEN'; 228 | RAISE NOTICE 'ALTER TABLE % SET (%);', v_schemaname || '.' || v_tablename || '_' || v_partitionname, v_options USING ERRCODE='ADYEN'; 229 | RAISE NOTICE 'XXXXXXXXX IMPORTANT XXXXXXXXX' USING ERRCODE='ADYEN'; 230 | -- EXECUTE format('ALTER TABLE ' || v_schemaname || '.' || v_tablename || ' SET (' || v_options || ');'); 231 | END IF; 232 | 233 | RAISE DEBUG 'Adding CHECK constraint on % called %_check, for % BETWEEN % AND %', 234 | v_schemaname || '.' || v_tablename || '_' || v_suffix, v_tablename || '_' || v_suffix, v_keycolumn, v_startkey, v_endkey USING ERRCODE='ADYEN'; 235 | EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I_%I_check CHECK ((%I IS NOT NULL) AND (%I >= %L AND %I < %L)) NOT VALID', 236 | v_schemaname, v_tablename || '_' || v_suffix, v_tablename, v_suffix, v_keycolumn, v_keycolumn, v_startkey, v_keycolumn, v_endkey); 237 | 238 | RAISE DEBUG 'Setting the % CHECK as VALID', v_tablename || '_'|| v_suffix || '_check' USING ERRCODE='ADYEN'; 239 | EXECUTE FORMAT('UPDATE pg_constraint AS c SET convalidated=true FROM pg_namespace n WHERE c.connamespace=n.oid AND conname=%L AND nspname=%L', 240 | v_tablename || '_' || v_suffix || '_check', v_schemaname); 241 | 242 | IF v_nopk IS TRUE THEN 243 | v_tablesource := v_tablename || '_template'; 244 | ELSE 245 | v_tablesource := v_tablename; 246 | END IF; 247 | 248 | RAISE DEBUG 'Attaching % as a child of %.', v_schemaname || '.' || v_tablename || '_' || v_suffix, v_schemaname || '.' || v_tablename USING ERRCODE='ADYEN'; 249 | IF v_coltype ~ 'int' THEN 250 | EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I_%I FOR VALUES FROM (%s) TO (%s)', 251 | v_schemaname, v_tablename, v_schemaname, v_tablename, v_suffix, v_startkey, v_endkey); 252 | 253 | RAISE DEBUG 'Creating new partition % based on %.', v_schemaname || '.' || v_tablename || '_' || v_partitionname, v_schemaname || '.' || v_tablesource USING ERRCODE='ADYEN'; 254 | EXECUTE format('CREATE TABLE %I.%I_%s (LIKE %I.%I INCLUDING ALL)', 255 | v_schemaname, v_tablename, v_partitionname, v_schemaname, v_tablesource 256 | ); 257 | EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I_%s FOR VALUES FROM (%s) TO (%s)', 258 | v_schemaname, v_tablename, v_schemaname, v_tablename, v_partitionname, v_newstart, v_newend); 259 | ELSE 260 | EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I_%I FOR VALUES FROM (%L) TO (%L)', 261 | v_schemaname, v_tablename, v_schemaname, v_tablename, v_suffix, v_startkey, v_endkey); 262 | 263 | RAISE DEBUG 'Creating new partition % based on %.', v_schemaname || '.' || v_tablename || '_' || v_partitionname, v_schemaname || '.' || v_tablesource USING ERRCODE='ADYEN'; 264 | EXECUTE format('CREATE TABLE %I.%I_%s (LIKE %I.%I INCLUDING ALL)', 265 | v_schemaname, v_tablename, v_partitionname, v_schemaname, v_tablesource 266 | ); 267 | EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I_%s FOR VALUES FROM (%L) TO (%L)', 268 | v_schemaname, v_tablename, v_schemaname, v_tablename, v_partitionname, v_newstart, v_newend); 269 | END IF; 270 | 271 | RAISE DEBUG 'Validating FKs which are referencing to the new partitioned table'; 272 | FOR v_references IN 273 | SELECT conn_table, conname, table_from 274 | FROM tmp_fks 275 | LOOP 276 | RAISE DEBUG 'Validating constraint % FROM %', v_references.conname, v_references.table_from USING ERRCODE='ADYEN'; 277 | EXECUTE FORMAT('UPDATE pg_constraint AS c SET convalidated=true WHERE conname=%L AND conrelid = %L', 278 | v_references.conname, v_references.conn_table ); 279 | END LOOP; 280 | 281 | DROP TABLE IF EXISTS tmp_trgs; 282 | DROP TABLE IF EXISTS tmp_fks; 283 | 284 | RETURN TRUE; 285 | 286 | END 287 | $func$; 288 | --------------------------------------------------------------------------------