Permalink
Browse files

Initial commit

  • Loading branch information...
0 parents commit 8326fb03611b2c541e6f31ba18f28b3272eb3805 @keithf4 committed Sep 5, 2012
@@ -0,0 +1 @@
+ignore/*
@@ -0,0 +1,47 @@
+{
+ "name": "pg_partmaint",
+ "abstract": "Extension to manage partitioned tables by time or ID",
+ "version": "0.1.0",
+ "maintainer": [
+ "Keith Fiske <keith@omniti.com>"
+ ],
+ "license": "postgresql",
+ "generated_by": "Keith Fiske",
+ "release_status": "testing",
+ "prereqs": {
+ "runtime": {
+ "requires": {
+ "PostgreSQL": "9.1.0",
+ "pg_jobmon": "0.3.0"
+ }
+ }
+ },
+ "provides": {
+ "pg_partmaint": {
+ "file": "sql/pg_partmaint.sql",
+ "docfile": "doc/partmaint.md",
+ "version": "0.1.0",
+ "abstract": "Extension to manage partitioned tables by time or ID"
+ }
+ },
+ "resources": {
+ "bugtracker": {
+ "web": "https://github.com/keithf4/pg_partmaint/issues"
+ },
+ "repository": {
+ "url": "git://github.com/keithf4/pg_partmaint.git" ,
+ "web": "https://github.com/keithf4/pg_partmaint",
+ "type": "git"
+ }
+ },
+ "meta-spec": {
+ "version": "1.0.0",
+ "url": "http://pgxn.org/meta/spec.txt"
+ },
+ "tags": [
+ "partition",
+ "partitions",
+ "table",
+ "tables"
+ ]
+}
@@ -0,0 +1,21 @@
+EXTENSION = pg_partmaint
+EXTVERSION = $(shell grep default_version $(EXTENSION).control | \
+ sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
+
+DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql))
+DOCS = $(wildcard doc/*.md)
+PG_CONFIG = pg_config
+PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes)
+
+ifeq ($(PG91),yes)
+all: sql/$(EXTENSION)--$(EXTVERSION).sql
+
+sql/$(EXTENSION)--$(EXTVERSION).sql: sql/types/*.sql sql/tables/*.sql sql/functions/*.sql
+ cat $^ > $@
+
+DATA = $(wildcard sql/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql
+EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql
+endif
+
+PGXS := $(shell $(PG_CONFIG) --pgxs)
+include $(PGXS)
No changes.
@@ -0,0 +1,4 @@
+default_version = '0.1.0'
+comment = 'Extension to manage partitioned tables by time or ID'
+requires = 'pg_jobmon'
+relocatable = false
@@ -0,0 +1,56 @@
+CREATE OR REPLACE FUNCTION part.create_next_partition (p_parent_table text) RETURNS void
+ LANGUAGE plpgsql
+ AS $$
+DECLARE
+
+v_datetime_string text;
+v_last_created text;
+v_last_partition_name text;
+v_next_partition_timestamp timestamp;
+v_part_interval interval;
+v_tablename text;
+v_type part.partition_type;
+
+
+BEGIN
+
+SELECT type
+ , part_interval
+ , last_created
+FROM part.part_config WHERE parent_table = p_parent_table
+INTO v_type, v_part_interval, v_last_created;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+-- Double check that last created partition exists
+IF v_last_created IS NOT NULL THEN
+ SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
+ IF v_tablename IS NULL THEN
+ RAISE EXCEPTION 'ERROR: previous partition missing. Unable to determine proper next partition name';
+ END IF;
+END IF;
+
+CASE
+ WHEN v_part_interval = '1 year' THEN
+ v_datetime_string := 'YYYY';
+ WHEN v_part_interval = '1 month' THEN
+ v_datetime_string := 'YYYY_MM';
+ WHEN v_part_interval = '1 week' THEN
+ v_datetime_string := 'YYYYwWW';
+ WHEN v_part_interval = '1 day' THEN
+ v_datetime_string := 'YYYY_MM_DD';
+ WHEN v_part_interval = '1 hour' OR v_part_interval = '30 mins' OR v_part_interval = '15 mins' THEN
+ v_datetime_string := 'YYYY_MM_DD_HH24MI';
+END CASE;
+
+-- pull out datetime portion of last partition's tablename
+v_next_partition_timestamp := to_timestamp(substring(v_last_created from char_length(p_parent_table||'_p')+1), v_datetime_string) + v_part_interval;
+
+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;
+
+UPDATE part.part_config SET last_created = v_last_partition_name WHERE parent_table = p_parent_table;
+
+RAISE NOTICE 'v_last_partition_name: %',v_last_partition_name;
+END
+$$;
@@ -0,0 +1,56 @@
+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
+ LANGUAGE plpgsql
+ AS $$
+DECLARE
+
+v_first_partition_time timestamp;
+v_interval interval;
+v_last_partition_name text;
+v_next_partition_time timestamp;
+v_tablename text;
+v_type part.partition_type;
+
+BEGIN
+
+SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
+ IF v_tablename IS NULL THEN
+ RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table;
+ END IF;
+
+IF p_scheme = 'id' THEN
+ RAISE EXCEPTION 'ID partitioning not supported yet. Please privide a time interval for partitioning';
+ -- v_type = 'id';
+ELSE
+ v_type = 'time';
+END IF;
+
+EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE';
+
+CASE
+ WHEN p_scheme = 'yearly' THEN
+ v_interval = '1 year';
+ WHEN p_scheme = 'monthly' THEN
+ v_interval = '1 month';
+ WHEN p_scheme = 'weekly' THEN
+ v_interval = '1 week';
+ WHEN p_scheme = 'daily' THEN
+ v_interval = '1 day';
+ WHEN p_scheme = 'hourly' THEN
+ v_interval = '1 hour';
+ WHEN p_scheme = 'half-hour' THEN
+ v_interval = '30 mins';
+ WHEN p_scheme = 'quarter-hour' THEN
+ v_interval = '15 mins';
+END CASE;
+
+-- create array variable here that adds as many timestamp values to the array as equals p_premake
+v_first_partition_time := CURRENT_TIMESTAMP;
+v_next_partition_time := CURRENT_TIMESTAMP + v_interval;
+
+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;
+
+INSERT INTO part.part_config (parent_table, type, part_interval, last_created) VALUES
+ (p_parent_table, v_type, v_interval, v_last_partition_name);
+
+END
+$$;
No changes.
@@ -0,0 +1,58 @@
+CREATE OR REPLACE FUNCTION part.create_partition (p_parent_table text, p_interval interval, p_partition_times timestamp[]) RETURNS text
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_time timestamp;
+v_partition_name text;
+
+BEGIN
+FOREACH v_time IN ARRAY p_partition_times LOOP
+ v_partition_name := p_parent_table || '_p';
+
+ 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
+ v_partition_name := v_partition_name || to_char(v_time, 'YYYY');
+ END IF;
+ IF p_interval = '1 week' THEN
+ v_partition_name := v_partition_name || 'w' || to_char(v_time, 'WW');
+ END IF;
+ 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
+ v_partition_name := v_partition_name || '_' || to_char(v_time, 'MM');
+ END IF;
+ IF p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
+ v_partition_name := v_partition_name || '_' || to_char(v_time, 'DD');
+ END IF;
+ IF p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
+ v_partition_name := v_partition_name || '_' || to_char(v_time, 'HH24');
+ IF p_interval <> '30 mins' AND p_interval <> '15 mins' THEN
+ v_partition_name := v_partition_name || '00';
+ END IF;
+ END IF;
+ IF p_interval = '30 mins' THEN
+ IF date_part('minute', v_time) < 30 THEN
+ v_partition_name := v_partition_name || '30';
+ ELSE
+ v_partition_name := v_partition_name || '00';
+ END IF;
+ ELSIF p_interval = '15 mins' THEN
+ IF date_part('minute', v_time) < 15 THEN
+ v_partition_name := v_partition_name || '15';
+ ELSIF date_part('minute', v_time) >= 15 AND date_part('minute', v_time) < 30 THEN
+ v_partition_name := v_partition_name || '30';
+ ELSIF date_part('minute', v_time) >= 30 AND date_part('minute', v_time) < 45 THEN
+ v_partition_name := v_partition_name || '45';
+ ELSE
+ v_partition_name := v_partition_name || '00';
+ END IF;
+ END IF;
+
+EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING CONSTRAINTS) INHERITS ('||p_parent_table||')';
+
+---- Call post_script() for given parent table
+
+END LOOP;
+
+RETURN v_partition_name;
+
+END
+$$;
No changes.
@@ -0,0 +1,19 @@
+/*
+ * Function to run any SQL after object recreation due to schema changes on source
+ */
+CREATE FUNCTION post_script(parent_table text) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+ v_post_script text[];
+ v_sql text;
+BEGIN
+
+ SELECT post_script INTO v_post_script FROM @extschema@.part_config WHERE parent_table = parent_table;
+
+ FOREACH v_sql IN ARRAY v_post_script LOOP
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql;
+ END LOOP;
+END
+$$;
@@ -0,0 +1,9 @@
+CREATE TABLE part.part_config (
+ parent_table text NOT NULL,
+ type part.partition_type NOT NULL,
+ part_interval text NOT NULL,
+ last_created text,
+
+ CONSTRAINT part_config_parent_table_pkey PRIMARY KEY (parent_table)
+);
+SELECT pg_catalog.pg_extension_config_dump('part_config', '');
@@ -0,0 +1,2 @@
+CREATE TYPE part.partition_type AS ENUM ('time', 'id');
+CREATE TYPE part.partition_interval AS ENUM ('yearly', 'monthly', 'weekly', 'daily', 'hourly', 'half-hour', 'quarter-hour', 'id');

0 comments on commit 8326fb0

Please sign in to comment.