Skip to content

Commit 8326fb0

Browse files
committed
Initial commit
0 parents  commit 8326fb0

13 files changed

+273
-0
lines changed

.gitignore

+1
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
ignore/*

META.json

+47
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
{
2+
"name": "pg_partmaint",
3+
"abstract": "Extension to manage partitioned tables by time or ID",
4+
"version": "0.1.0",
5+
"maintainer": [
6+
"Keith Fiske <keith@omniti.com>"
7+
],
8+
"license": "postgresql",
9+
"generated_by": "Keith Fiske",
10+
"release_status": "testing",
11+
"prereqs": {
12+
"runtime": {
13+
"requires": {
14+
"PostgreSQL": "9.1.0",
15+
"pg_jobmon": "0.3.0"
16+
}
17+
}
18+
},
19+
"provides": {
20+
"pg_partmaint": {
21+
"file": "sql/pg_partmaint.sql",
22+
"docfile": "doc/partmaint.md",
23+
"version": "0.1.0",
24+
"abstract": "Extension to manage partitioned tables by time or ID"
25+
}
26+
},
27+
"resources": {
28+
"bugtracker": {
29+
"web": "https://github.com/keithf4/pg_partmaint/issues"
30+
},
31+
"repository": {
32+
"url": "git://github.com/keithf4/pg_partmaint.git" ,
33+
"web": "https://github.com/keithf4/pg_partmaint",
34+
"type": "git"
35+
}
36+
},
37+
"meta-spec": {
38+
"version": "1.0.0",
39+
"url": "http://pgxn.org/meta/spec.txt"
40+
},
41+
"tags": [
42+
"partition",
43+
"partitions",
44+
"table",
45+
"tables"
46+
]
47+
}

Makefile

+21
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
EXTENSION = pg_partmaint
2+
EXTVERSION = $(shell grep default_version $(EXTENSION).control | \
3+
sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
4+
5+
DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql))
6+
DOCS = $(wildcard doc/*.md)
7+
PG_CONFIG = pg_config
8+
PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes)
9+
10+
ifeq ($(PG91),yes)
11+
all: sql/$(EXTENSION)--$(EXTVERSION).sql
12+
13+
sql/$(EXTENSION)--$(EXTVERSION).sql: sql/types/*.sql sql/tables/*.sql sql/functions/*.sql
14+
cat $^ > $@
15+
16+
DATA = $(wildcard sql/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql
17+
EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql
18+
endif
19+
20+
PGXS := $(shell $(PG_CONFIG) --pgxs)
21+
include $(PGXS)

README.md

Whitespace-only changes.

pg_partmaint.control

+4
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,4 @@
1+
default_version = '0.1.0'
2+
comment = 'Extension to manage partitioned tables by time or ID'
3+
requires = 'pg_jobmon'
4+
relocatable = false
+56
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,56 @@
1+
CREATE OR REPLACE FUNCTION part.create_next_partition (p_parent_table text) RETURNS void
2+
LANGUAGE plpgsql
3+
AS $$
4+
DECLARE
5+
6+
v_datetime_string text;
7+
v_last_created text;
8+
v_last_partition_name text;
9+
v_next_partition_timestamp timestamp;
10+
v_part_interval interval;
11+
v_tablename text;
12+
v_type part.partition_type;
13+
14+
15+
BEGIN
16+
17+
SELECT type
18+
, part_interval
19+
, last_created
20+
FROM part.part_config WHERE parent_table = p_parent_table
21+
INTO v_type, v_part_interval, v_last_created;
22+
IF NOT FOUND THEN
23+
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
24+
END IF;
25+
26+
-- Double check that last created partition exists
27+
IF v_last_created IS NOT NULL THEN
28+
SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
29+
IF v_tablename IS NULL THEN
30+
RAISE EXCEPTION 'ERROR: previous partition missing. Unable to determine proper next partition name';
31+
END IF;
32+
END IF;
33+
34+
CASE
35+
WHEN v_part_interval = '1 year' THEN
36+
v_datetime_string := 'YYYY';
37+
WHEN v_part_interval = '1 month' THEN
38+
v_datetime_string := 'YYYY_MM';
39+
WHEN v_part_interval = '1 week' THEN
40+
v_datetime_string := 'YYYYwWW';
41+
WHEN v_part_interval = '1 day' THEN
42+
v_datetime_string := 'YYYY_MM_DD';
43+
WHEN v_part_interval = '1 hour' OR v_part_interval = '30 mins' OR v_part_interval = '15 mins' THEN
44+
v_datetime_string := 'YYYY_MM_DD_HH24MI';
45+
END CASE;
46+
47+
-- pull out datetime portion of last partition's tablename
48+
v_next_partition_timestamp := to_timestamp(substring(v_last_created from char_length(p_parent_table||'_p')+1), v_datetime_string) + v_part_interval;
49+
50+
EXECUTE 'SELECT part.create_partition('||quote_literal(p_parent_table)||','||quote_literal(v_part_interval)||','||quote_literal(ARRAY[v_next_partition_timestamp])||')' INTO v_last_partition_name;
51+
52+
UPDATE part.part_config SET last_created = v_last_partition_name WHERE parent_table = p_parent_table;
53+
54+
RAISE NOTICE 'v_last_partition_name: %',v_last_partition_name;
55+
END
56+
$$;

sql/functions/create_parent.sql

+56
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,56 @@
1+
CREATE OR REPLACE FUNCTION part.create_parent(p_parent_table text, p_scheme part.partition_interval, p_premake int, p_id_series int DEFAULT NULL, p_debug boolean DEFAULT false) RETURNS void
2+
LANGUAGE plpgsql
3+
AS $$
4+
DECLARE
5+
6+
v_first_partition_time timestamp;
7+
v_interval interval;
8+
v_last_partition_name text;
9+
v_next_partition_time timestamp;
10+
v_tablename text;
11+
v_type part.partition_type;
12+
13+
BEGIN
14+
15+
SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
16+
IF v_tablename IS NULL THEN
17+
RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table;
18+
END IF;
19+
20+
IF p_scheme = 'id' THEN
21+
RAISE EXCEPTION 'ID partitioning not supported yet. Please privide a time interval for partitioning';
22+
-- v_type = 'id';
23+
ELSE
24+
v_type = 'time';
25+
END IF;
26+
27+
EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE';
28+
29+
CASE
30+
WHEN p_scheme = 'yearly' THEN
31+
v_interval = '1 year';
32+
WHEN p_scheme = 'monthly' THEN
33+
v_interval = '1 month';
34+
WHEN p_scheme = 'weekly' THEN
35+
v_interval = '1 week';
36+
WHEN p_scheme = 'daily' THEN
37+
v_interval = '1 day';
38+
WHEN p_scheme = 'hourly' THEN
39+
v_interval = '1 hour';
40+
WHEN p_scheme = 'half-hour' THEN
41+
v_interval = '30 mins';
42+
WHEN p_scheme = 'quarter-hour' THEN
43+
v_interval = '15 mins';
44+
END CASE;
45+
46+
-- create array variable here that adds as many timestamp values to the array as equals p_premake
47+
v_first_partition_time := CURRENT_TIMESTAMP;
48+
v_next_partition_time := CURRENT_TIMESTAMP + v_interval;
49+
50+
EXECUTE 'SELECT part.create_partition('||quote_literal(p_parent_table)||','||quote_literal(v_interval)||','||quote_literal(ARRAY[v_first_partition_time, v_next_partition_time])||')' INTO v_last_partition_name;
51+
52+
INSERT INTO part.part_config (parent_table, type, part_interval, last_created) VALUES
53+
(p_parent_table, v_type, v_interval, v_last_partition_name);
54+
55+
END
56+
$$;

sql/functions/create_part_func.sql

Whitespace-only changes.

sql/functions/create_partition.sql

+58
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
CREATE OR REPLACE FUNCTION part.create_partition (p_parent_table text, p_interval interval, p_partition_times timestamp[]) RETURNS text
2+
LANGUAGE plpgsql SECURITY DEFINER
3+
AS $$
4+
DECLARE
5+
6+
v_time timestamp;
7+
v_partition_name text;
8+
9+
BEGIN
10+
FOREACH v_time IN ARRAY p_partition_times LOOP
11+
v_partition_name := p_parent_table || '_p';
12+
13+
IF p_interval = '1 year' OR p_interval = '1 month' OR p_interval = '1 week' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
14+
v_partition_name := v_partition_name || to_char(v_time, 'YYYY');
15+
END IF;
16+
IF p_interval = '1 week' THEN
17+
v_partition_name := v_partition_name || 'w' || to_char(v_time, 'WW');
18+
END IF;
19+
IF p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
20+
v_partition_name := v_partition_name || '_' || to_char(v_time, 'MM');
21+
END IF;
22+
IF p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
23+
v_partition_name := v_partition_name || '_' || to_char(v_time, 'DD');
24+
END IF;
25+
IF p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
26+
v_partition_name := v_partition_name || '_' || to_char(v_time, 'HH24');
27+
IF p_interval <> '30 mins' AND p_interval <> '15 mins' THEN
28+
v_partition_name := v_partition_name || '00';
29+
END IF;
30+
END IF;
31+
IF p_interval = '30 mins' THEN
32+
IF date_part('minute', v_time) < 30 THEN
33+
v_partition_name := v_partition_name || '30';
34+
ELSE
35+
v_partition_name := v_partition_name || '00';
36+
END IF;
37+
ELSIF p_interval = '15 mins' THEN
38+
IF date_part('minute', v_time) < 15 THEN
39+
v_partition_name := v_partition_name || '15';
40+
ELSIF date_part('minute', v_time) >= 15 AND date_part('minute', v_time) < 30 THEN
41+
v_partition_name := v_partition_name || '30';
42+
ELSIF date_part('minute', v_time) >= 30 AND date_part('minute', v_time) < 45 THEN
43+
v_partition_name := v_partition_name || '45';
44+
ELSE
45+
v_partition_name := v_partition_name || '00';
46+
END IF;
47+
END IF;
48+
49+
EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING CONSTRAINTS) INHERITS ('||p_parent_table||')';
50+
51+
---- Call post_script() for given parent table
52+
53+
END LOOP;
54+
55+
RETURN v_partition_name;
56+
57+
END
58+
$$;

sql/functions/create_trigger.sql

Whitespace-only changes.

sql/functions/post_script.sql

+19
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
/*
2+
* Function to run any SQL after object recreation due to schema changes on source
3+
*/
4+
CREATE FUNCTION post_script(parent_table text) RETURNS void
5+
LANGUAGE plpgsql SECURITY DEFINER
6+
AS $$
7+
DECLARE
8+
v_post_script text[];
9+
v_sql text;
10+
BEGIN
11+
12+
SELECT post_script INTO v_post_script FROM @extschema@.part_config WHERE parent_table = parent_table;
13+
14+
FOREACH v_sql IN ARRAY v_post_script LOOP
15+
RAISE NOTICE 'v_sql: %', v_sql;
16+
EXECUTE v_sql;
17+
END LOOP;
18+
END
19+
$$;

sql/tables/tables.sql

+9
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,9 @@
1+
CREATE TABLE part.part_config (
2+
parent_table text NOT NULL,
3+
type part.partition_type NOT NULL,
4+
part_interval text NOT NULL,
5+
last_created text,
6+
7+
CONSTRAINT part_config_parent_table_pkey PRIMARY KEY (parent_table)
8+
);
9+
SELECT pg_catalog.pg_extension_config_dump('part_config', '');

sql/types/types.sql

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
CREATE TYPE part.partition_type AS ENUM ('time', 'id');
2+
CREATE TYPE part.partition_interval AS ENUM ('yearly', 'monthly', 'weekly', 'daily', 'hourly', 'half-hour', 'quarter-hour', 'id');

0 commit comments

Comments
 (0)