Skip to content

Commit

Permalink
add pg_partman
Browse files Browse the repository at this point in the history
  • Loading branch information
olirice committed Sep 10, 2024
1 parent 5305719 commit 29ef673
Show file tree
Hide file tree
Showing 7 changed files with 320 additions and 6 deletions.
1 change: 1 addition & 0 deletions flake.nix
Original file line number Diff line number Diff line change
Expand Up @@ -111,6 +111,7 @@
./nix/ext/pg_hashids.nix
./nix/ext/pgsodium.nix
./nix/ext/pg_graphql.nix
./nix/ext/pg_partman.nix
./nix/ext/pg_stat_monitor.nix
./nix/ext/pg_jsonschema.nix
./nix/ext/pgvector.nix
Expand Down
34 changes: 34 additions & 0 deletions nix/ext/pg_partman.nix
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
{ lib, stdenv, fetchFromGitHub, postgresql }:

stdenv.mkDerivation rec {
pname = "pg_partman";
version = "5.1.0";

buildInputs = [ postgresql ];

src = fetchFromGitHub {
owner = "pgpartman";
repo = pname;
rev = "refs/tags/v${version}";
sha256 = "sha256-GrVOJ5ywZMyqyDroYDLdKkXDdIJSDGhDfveO/ZvrmYs=";
};

installPhase = ''
mkdir -p $out/{lib,share/postgresql/extension}
cp src/*${postgresql.dlSuffix} $out/lib
cp updates/* $out/share/postgresql/extension
cp -r sql/* $out/share/postgresql/extension
cp *.control $out/share/postgresql/extension
'';

meta = with lib; {
description = "Partition management extension for PostgreSQL";
homepage = "https://github.com/pgpartman/pg_partman";
changelog = "https://github.com/pgpartman/pg_partman/blob/v${version}/CHANGELOG.md";
maintainers = with maintainers; [ samrose ];
platforms = postgresql.meta.platforms;
license = licenses.postgresql;
broken = versionOlder postgresql.version "14";
};
}
105 changes: 100 additions & 5 deletions nix/tests/expected/extensions_sql_interface.out

Large diffs are not rendered by default.

101 changes: 101 additions & 0 deletions nix/tests/expected/pg_partman.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,101 @@
create schema if not exists partman_test;
/*
Simple Time Based: 1 Partition Per Day

For native partitioning, you must start with a parent table that has already been set up to be partitioned in the desired type. Currently pg_partman only supports the RANGE type of partitioning (both for time & id). You cannot turn a non-partitioned table into the parent table of a partitioned set, which can make migration a challenge. This document will show you some techniques for how to manage this later. For now, we will start with a brand new table in this example. Any non-unique indexes can also be added to the parent table in PG11+ and they will automatically be created on all child tables.
*/
create table partman_test.time_taptest_table(
col1 int,
col2 text default 'stuff',
col3 timestamptz not null default now()
)
partition by range (col3);
create index on partman_test.time_tap (col3);
ERROR: relation "partman_test.time_tap" does not exist
/*
Unique indexes (including primary keys) cannot be created on a natively partitioned parent unless they include the partition key. For time-based partitioning that generally doesn't work out since that would limit only a single timestamp value in each child table. pg_partman helps to manage this by using a template table to manage properties that currently are not supported by native partitioning. Note that this does not solve the issue of the constraint not being enforced across the entire partition set. See the main documentation to see which properties are managed by the template.

Manually create the template table first so that when we run create_parent() the initial child tables that are created will have a primary key. If you do not supply a template table to pg_partman, it will create one for you in the schema that you installed the extension to. However properties you add to that template are only then applied to newly created child tables after that point. You will have to retroactively apply those properties manually to any child tables that already existed.
*/
create table partman_test.time_taptest_table_template (like partman_test.time_taptest_table);
alter table partman_test.time_taptest_table_template add primary key (col1);
/*
Review tables in the partman_test schema
*/
select
table_name,
table_type
from
information_schema.tables
where
table_schema = 'partman_test';
table_name | table_type
-----------------------------+------------
time_taptest_table | BASE TABLE
time_taptest_table_template | BASE TABLE
(2 rows)

select public.create_parent(
p_parent_table := 'partman_test.time_taptest_table',
p_control := 'col3',
p_interval := '1 day',
p_template_table := 'partman_test.time_taptest_table_template'
);
create_parent
---------------
t
(1 row)

/*
Review tables in the partman_test schema, which should now include daily partitions
*/
select
-- dates in partition names are variable, so reduced to the prefix
substring(table_name, 1, 21) as table_prefix,
table_type
from
information_schema.tables
where
table_schema = 'partman_test'
order by
table_name;
table_prefix | table_type
-----------------------+------------
time_taptest_table | BASE TABLE
time_taptest_table_de | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_p2 | BASE TABLE
time_taptest_table_te | BASE TABLE
(12 rows)

/*
Confirm maintenance proc runs without issue
*/
call public.run_maintenance_proc();
/*
Make sure the background worker is NOT enabled.
This is intentional. We document using pg_cron to schedule calls to
public.run_maintenance_proc(). That is consistent with other providers.
*/
select
application_name
from
pg_stat_activity
where
application_name = 'pg_partman_bgw';
application_name
------------------
(0 rows)

-- Cleanup
drop schema partman_test cascade;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table partman_test.time_taptest_table
drop cascades to table partman_test.time_taptest_table_template
2 changes: 1 addition & 1 deletion nix/tests/postgresql.conf.in
Original file line number Diff line number Diff line change
Expand Up @@ -718,7 +718,7 @@ default_text_search_config = 'pg_catalog.english'

#local_preload_libraries = ''
#session_preload_libraries = ''
shared_preload_libraries = 'pg_stat_statements, pg_stat_monitor, pgaudit, plpgsql, plpgsql_check, pg_cron, pg_net, pgsodium, timescaledb, auto_explain, pg_tle, plan_filter, pg_backtrace' # (change requires restart)
shared_preload_libraries = 'pg_stat_statements, pg_stat_monitor, pgaudit, plpgsql, plpgsql_check, pg_cron, pg_net, pgsodium, timescaledb, auto_explain, pg_tle, plan_filter, pg_backtrace, pg_partman_bgw' # (change requires restart)
jit_provider = 'llvmjit' # JIT library to use


Expand Down
1 change: 1 addition & 0 deletions nix/tests/prime.sql
Original file line number Diff line number Diff line change
Expand Up @@ -42,6 +42,7 @@ create extension pg_net;
create extension pg_graphql;
create extension pg_freespacemap;
create extension pg_hashids;
create extension pg_partman;
create extension pg_prewarm;
create extension pg_jsonschema;
create extension pg_repack;
Expand Down
82 changes: 82 additions & 0 deletions nix/tests/sql/pg_partman.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
create schema if not exists partman_test;

/*
Simple Time Based: 1 Partition Per Day
For native partitioning, you must start with a parent table that has already been set up to be partitioned in the desired type. Currently pg_partman only supports the RANGE type of partitioning (both for time & id). You cannot turn a non-partitioned table into the parent table of a partitioned set, which can make migration a challenge. This document will show you some techniques for how to manage this later. For now, we will start with a brand new table in this example. Any non-unique indexes can also be added to the parent table in PG11+ and they will automatically be created on all child tables.
*/

create table partman_test.time_taptest_table(
col1 int,
col2 text default 'stuff',
col3 timestamptz not null default now()
)
partition by range (col3);

create index on partman_test.time_tap (col3);

/*
Unique indexes (including primary keys) cannot be created on a natively partitioned parent unless they include the partition key. For time-based partitioning that generally doesn't work out since that would limit only a single timestamp value in each child table. pg_partman helps to manage this by using a template table to manage properties that currently are not supported by native partitioning. Note that this does not solve the issue of the constraint not being enforced across the entire partition set. See the main documentation to see which properties are managed by the template.
Manually create the template table first so that when we run create_parent() the initial child tables that are created will have a primary key. If you do not supply a template table to pg_partman, it will create one for you in the schema that you installed the extension to. However properties you add to that template are only then applied to newly created child tables after that point. You will have to retroactively apply those properties manually to any child tables that already existed.
*/

create table partman_test.time_taptest_table_template (like partman_test.time_taptest_table);

alter table partman_test.time_taptest_table_template add primary key (col1);

/*
Review tables in the partman_test schema
*/

select
table_name,
table_type
from
information_schema.tables
where
table_schema = 'partman_test';


select public.create_parent(
p_parent_table := 'partman_test.time_taptest_table',
p_control := 'col3',
p_interval := '1 day',
p_template_table := 'partman_test.time_taptest_table_template'
);

/*
Review tables in the partman_test schema, which should now include daily partitions
*/

select
-- dates in partition names are variable, so reduced to the prefix
substring(table_name, 1, 21) as table_prefix,
table_type
from
information_schema.tables
where
table_schema = 'partman_test'
order by
table_name;


/*
Confirm maintenance proc runs without issue
*/
call public.run_maintenance_proc();

/*
Make sure the background worker is NOT enabled.
This is intentional. We document using pg_cron to schedule calls to
public.run_maintenance_proc(). That is consistent with other providers.
*/
select
application_name
from
pg_stat_activity
where
application_name = 'pg_partman_bgw';

-- Cleanup
drop schema partman_test cascade;

0 comments on commit 29ef673

Please sign in to comment.