├── README.md ├── setup.sql ├── update_partitions.sql ├── update_partitions_no_unknown_table.sql └── update_partitions_no_unknown_table_with_timezone.sql /README.md: -------------------------------------------------------------------------------- 1 | postgresql-time-series-table-partitions 2 | ======================================= 3 | 4 | Originally for monthly table partitions, more info at [imperialwicket.com](http://imperialwicket.com/postgresql-automating-monthly-table-partitions). 5 | 6 | This currently duplicates a [similar gist](https://gist.github.com/imperialwicket/2720074), but revision maintenance and change requests were becoming burdensome. 7 | 8 | Eventually I'll copy over data from the blog post to this readme (PR requests welcome for this and any other changes!). 9 | 10 | 11 | Note that `update_partitions.sql` and `update_partitions_no_unknown_table.sql` are mutually exclusive. `update_partitions.sql` creates an 'unknown' table, and any dated inserts that don't have an appropriate child table automatically go here. If you have dirty data, or want to pay close attention to inserts for reporting, this could work well for you. `update_partitions_no_unknown_table.sql` has an alternate trigger that will dynamically create a missing child table for the appropriate date interval when an 'unknown' insert occurs. If you have unpredictable data that should always be well-organized, this alternative could be more productive than managing the unknown table (thanks @sandinosaso for this!). The trigger in `update_partitions_no_unknown_table.sql` relies on syntax available in Postgres 9.1 and newer. 12 | -------------------------------------------------------------------------------- /setup.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Setup - Add plpgsql, create a parent table, create an initial child table, 3 | -- create the trigger and the initial trigger function. 4 | -- 5 | 6 | -- We'll need plpgsql, so create it in your db if it's not already available. 7 | CREATE LANGUAGE plpgsql; 8 | 9 | -- Create a table to act as parent with the appropriate columns for your data. 10 | CREATE TABLE my_schema.my_data (name varchar(24), create_date timestamp); 11 | 12 | -- Create an initial child table so that you can create the function/trigger without errors 13 | CREATE TABLE my_schema.my_data_201001 14 | (CHECK (create_date >= '2010-01-01' AND create_date < '2010-02-01')) 15 | INHERITS (my_schema.my_data); 16 | -- Add an index to your child tables. 17 | CREATE INDEX idx_my_data_201001 ON my_schema.my_data_201001 (create_date); 18 | 19 | -- Create the initial function to handle inserting to child tables 20 | CREATE OR REPLACE FUNCTION my_schema.my_data_insert_trigger_function() 21 | RETURNS TRIGGER AS $$ 22 | BEGIN 23 | IF ( NEW.create_date >= '2010-01-01' AND NEW.create_date < '2010-02-01' ) THEN 24 | INSERT INTO my_schema.my_data_201001 VALUES (NEW.*); 25 | ELSE 26 | RAISE EXCEPTION 'Date out of range. Fix parent_insert_trigger_function()!'; 27 | END IF; 28 | RETURN NULL; 29 | END; 30 | $$ 31 | LANGUAGE plpgsql; 32 | 33 | -- Create a trigger to call the function before insert. 34 | CREATE TRIGGER my_data_insert_trigger 35 | BEFORE INSERT ON my_schema.my_data 36 | FOR EACH ROW EXECUTE PROCEDURE my_schema.my_data_insert_trigger_function(); 37 | 38 | 39 | -- 40 | -- Notice that: INSERT INTO my_schema.my_data VALUES ('somename','2010-01-10'); 41 | -- inserts into the my_data_201001 table. 42 | -- Notice that: INSERT INTO my_schema.my_data VALUES ('somename','2010-02-10'); 43 | -- raises an error, and does not insert anything. 44 | -- Notice that: SELECT * FROM my_schema.my_data; 45 | -- returns records from the child tables. 46 | -- -------------------------------------------------------------------------------- /update_partitions.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Update_partitions - Takes a begin time, schema name, primary (parent) table name, 3 | -- table owner, the name of the date column, 4 | -- and if we want 'week'ly or 'month'ly partitions. 5 | -- The number of created tables is returned. 6 | -- ex: SELECT public.update_partitions('2010-02-01','my_schema','my_data','postgres','create_date','week') 7 | -- 8 | 9 | 10 | -- Function: public.update_partitions(timestamp without time zone, text, text, text, text, text) 11 | 12 | -- DROP FUNCTION public.update_partitions(timestamp without time zone, text, text, text, text, text); 13 | 14 | CREATE OR REPLACE FUNCTION public.update_partitions(begin_time timestamp without time zone, schema_name text, primary_table_name text, table_owner text, date_column text, plan text) 15 | RETURNS integer AS 16 | $BODY$ 17 | declare startTime timestamp; 18 | declare endTime timestamp; 19 | declare intervalTime timestamp; 20 | declare createStmts text; 21 | declare createTrigger text; 22 | declare fullTablename text; 23 | declare unknownTablename text; 24 | declare triggerName text; 25 | declare createdTables integer; 26 | declare dateFormat text; 27 | declare planInterval interval; 28 | 29 | BEGIN 30 | dateFormat:=CASE WHEN plan='month' THEN 'YYYYMM' 31 | WHEN plan='week' THEN 'IYYYIW' 32 | WHEN plan='day' THEN 'YYYYDDD' 33 | WHEN plan='year' THEN 'YYYY' 34 | ELSE 'error' 35 | END; 36 | IF dateFormat='error' THEN 37 | RAISE EXCEPTION 'Non valid plan --> %', plan; 38 | END IF; 39 | -- Store the incoming begin_time, and set the endTime to one month/week/day in the future 40 | -- (this allows use of a cronjob at any time during the month/week/day to generate next month/week/day's table) 41 | startTime:=(date_trunc(plan,begin_time)); 42 | planInterval:=('1 '||plan)::interval; 43 | endTime:=(date_trunc(plan,(current_timestamp + planInterval))); 44 | createdTables:=0; 45 | 46 | -- Begin creating the trigger function, we're going to generate it backwards. 47 | createTrigger:=' 48 | ELSE 49 | INSERT INTO '||schema_name||'.'||primary_table_name||'_unknowns VALUES (NEW.*); 50 | END IF; 51 | RETURN NULL; 52 | END; 53 | $$ 54 | LANGUAGE plpgsql;'; 55 | 56 | while (startTime <= endTime) loop 57 | 58 | fullTablename:=primary_table_name||'_'||to_char(startTime,dateFormat); 59 | intervalTime:= startTime + planInterval; 60 | 61 | -- The table creation sql statement 62 | if not exists(select * from information_schema.tables where table_schema = schema_name AND table_name = fullTablename) then 63 | createStmts:='CREATE TABLE '||schema_name||'.'||fullTablename||' ( 64 | CHECK ('||date_column||' >= '''||startTime||''' AND '||date_column||' < '''||intervalTime||''') 65 | ) INHERITS ('||schema_name||'.'||primary_table_name||')'; 66 | 67 | -- Run the table creation 68 | EXECUTE createStmts; 69 | 70 | -- Set the table owner 71 | createStmts :='ALTER TABLE '||schema_name||'.'||fullTablename||' OWNER TO '||table_owner||';'; 72 | EXECUTE createStmts; 73 | 74 | -- Create an index on the timestamp 75 | createStmts:='CREATE INDEX idx_'||fullTablename||'_'||date_column||' ON '||schema_name||'.'||fullTablename||' ('||date_column||');'; 76 | EXECUTE createStmts; 77 | 78 | -- Track how many tables we are creating (should likely be 1, except for initial run and backfilling efforts). 79 | createdTables:=createdTables+1; 80 | end if; 81 | 82 | -- Add case for this table to trigger creation sql statement. 83 | createTrigger:='( NEW.'||date_column||' >= TIMESTAMP '''||startTime||''' AND NEW.'||date_column||' < TIMESTAMP '''||intervalTime||''' ) THEN 84 | INSERT INTO '||schema_name||'.'||fullTablename||' VALUES (NEW.*); '||createTrigger; 85 | 86 | startTime:=intervalTime; 87 | 88 | if (startTime <= endTime) 89 | then 90 | createTrigger:=' 91 | ELSEIF '||createTrigger; 92 | end if; 93 | 94 | end loop; 95 | 96 | -- CREATE UNKNOWN HOLDER IF IT DOES NOT EXIST, unknowns table handles possible 97 | -- inserts for which there is not an appropriate table partition 98 | -- This is often more desirable than simply raising an error. 99 | unknownTablename:=primary_table_name||'_unknowns'; 100 | IF NOT EXISTS(SELECT * FROM information_schema.tables 101 | WHERE table_schema = schema_name 102 | AND table_name = unknownTablename) 103 | THEN 104 | createStmts :='CREATE TABLE '||schema_name||'.'||primary_table_name||'_unknowns ( 105 | ) INHERITS ('||schema_name||'.'||primary_table_name||');'; 106 | 107 | -- Execute the unknown table creation 108 | EXECUTE createStmts; 109 | 110 | -- Set the table owner 111 | createStmts:='ALTER TABLE '||schema_name||'.'||primary_table_name||'_unknowns OWNER TO '||table_owner||';'; 112 | EXECUTE createStmts; 113 | 114 | END IF; 115 | 116 | -- Finish creating the trigger function (at the beginning). 117 | createTrigger:='CREATE OR REPLACE FUNCTION '||schema_name||'.'||primary_table_name||'_insert_trigger_function() 118 | RETURNS TRIGGER AS $$ 119 | BEGIN 120 | IF '||createTrigger; 121 | 122 | -- Run the trigger replacement; 123 | EXECUTE createTrigger; 124 | 125 | -- Create the trigger that uses the trigger function, if it isn't already created 126 | triggerName:=primary_table_name||'_insert_trigger'; 127 | if not exists(select * from information_schema.triggers where trigger_name = triggerName) then 128 | createTrigger:='CREATE TRIGGER '||primary_table_name||'_insert_trigger 129 | BEFORE INSERT ON '||schema_name||'.'||primary_table_name||' 130 | FOR EACH ROW EXECUTE PROCEDURE '||schema_name||'.'||primary_table_name||'_insert_trigger_function();'; 131 | EXECUTE createTrigger; 132 | END if; 133 | return createdTables; 134 | END; 135 | $BODY$ 136 | LANGUAGE 'plpgsql' VOLATILE 137 | COST 100; 138 | ALTER FUNCTION public.update_partitions(timestamp without time zone, text, text, text, text, text) OWNER TO postgres; -------------------------------------------------------------------------------- /update_partitions_no_unknown_table.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Update_partitions - Takes a begin time, schema name, primary (parent) table name, 3 | -- table owner, an expression which returns a date, 4 | -- and if we want 'week'ly or 'month'ly partitions. 5 | -- The number of created tables is returned. 6 | -- ex: SELECT public.create_date_partitions_for_table('2010-02-01','my_schema','my_data','postgres','create_date','week',1,true,true) 7 | -- 8 | 9 | -- Function: public.create_date_partitions_for_table(timestamp without time zone, regclass, text, interval, boolean, boolean) 10 | 11 | -- DROP FUNCTION public.create_date_partitions_for_table(timestamp without time zone, regclass, text, interval, boolean, boolean); 12 | 13 | CREATE OR REPLACE FUNCTION public.create_date_partitions_for_table(begin_time timestamp without time zone, 14 | primary_table regclass, 15 | date_expression text, 16 | spacing interval, 17 | fill_child_tables boolean, 18 | truncate_parent_table boolean) 19 | RETURNS integer AS 20 | $BODY$ 21 | DECLARE startTime timestamp; 22 | DECLARE endTime timestamp; 23 | DECLARE intervalTime timestamp; 24 | DECLARE createStmts text; 25 | DECLARE insertStmts text; 26 | DECLARE createTrigger text; 27 | DECLARE fullTablename text; 28 | DECLARE triggerName text; 29 | DECLARE createdTables integer; 30 | DECLARE intervalEpoch integer; 31 | DECLARE dateFormat text; 32 | DECLARE dateColumnName text; 33 | DECLARE tableOwner text; 34 | DECLARE primary_table_name text; 35 | DECLARE schema_name text; 36 | 37 | BEGIN 38 | -- determine if the date_expression is a valid identifier 39 | dateColumnName := CASE WHEN date_expression ~* '^[a-z0-9_$]+$' THEN date_expression ELSE 'date' END; 40 | 41 | -- determine the date format for the given interval 42 | intervalEpoch := EXTRACT(EPOCH FROM spacing); 43 | dateFormat := CASE WHEN intervalEpoch < EXTRACT(EPOCH FROM interval '1 day') THEN 'error' 44 | WHEN intervalEpoch < EXTRACT(EPOCH FROM interval '1 week') THEN 'YYYYDDD' 45 | WHEN intervalEpoch < EXTRACT(EPOCH FROM interval '1 month') THEN 'IYYYIW' 46 | WHEN intervalEpoch < EXTRACT(EPOCH FROM interval '1 year') THEN 'YYYYMM' 47 | ELSE 'YYYY' 48 | END; 49 | IF dateFormat = 'error' THEN 50 | RAISE EXCEPTION 'Interval must be greater than 1 day'; 51 | END IF; 52 | 53 | -- get the table name, schema and owner 54 | SELECT c.relname, n.nspname, a.rolname INTO primary_table_name, schema_name, tableOwner 55 | FROM pg_catalog.pg_class AS c 56 | JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid 57 | JOIN pg_catalog.pg_authid AS a ON c.relowner = a.oid 58 | WHERE c.oid = primary_table::oid; 59 | 60 | -- Store the incoming begin_time, and set the endTime to one month/week/day in the future 61 | -- (this allows use of a cronjob at any time during the month/week/day to generate next month/week/day's table) 62 | startTime := to_timestamp(to_char(begin_time, dateFormat), dateFormat); 63 | endTime := to_timestamp(to_char(now() + spacing, dateFormat), dateFormat); 64 | createdTables := 0; 65 | 66 | WHILE (startTime <= endTime) LOOP 67 | 68 | fullTablename := primary_table_name||'_'||to_char(startTime, dateFormat); 69 | intervalTime := startTime + spacing; 70 | 71 | -- The table creation sql statement 72 | IF NOT EXISTS(SELECT * FROM information_schema.tables WHERE table_schema = schema_name AND table_name = fullTablename) THEN 73 | createStmts := 'CREATE TABLE '||schema_name||'.'||fullTablename||' ( 74 | CHECK ('||date_expression||' >= '''||startTime||''' AND '||date_expression||' < '''||intervalTime||''') 75 | ) INHERITS ('||schema_name||'.'||primary_table_name||')'; 76 | 77 | -- Run the table creation 78 | EXECUTE createStmts; 79 | 80 | -- Set the table owner 81 | createStmts := 'ALTER TABLE '||schema_name||'.'||fullTablename||' OWNER TO "'||tableOwner||'";'; 82 | EXECUTE createStmts; 83 | 84 | -- Create an index on the timestamp 85 | createStmts := 'CREATE INDEX idx_'||fullTablename||'_'||dateColumnName||' ON '||schema_name||'.'||fullTablename||' ('||date_expression||');'; 86 | EXECUTE createStmts; 87 | 88 | RAISE NOTICE 'Child table %.% created',schema_name,fullTablename; 89 | 90 | --if fill_child_tables is true then we fill the child table with the parent's table data that satisfies the child's table check constraint 91 | IF (fill_child_tables) THEN 92 | RAISE NOTICE 'Filling child table %.%',schema_name,fullTablename; 93 | insertStmts := 'INSERT INTO '||schema_name||'.'||fullTablename||' ( 94 | SELECT * FROM '||schema_name||'.'||primary_table_name||' 95 | WHERE '||date_expression||' >= '''||startTime||''' AND 96 | '||date_expression||' < '''||intervalTime||''' 97 | );'; 98 | EXECUTE insertStmts; 99 | END IF; 100 | 101 | -- Track how many tables we are creating (should likely be 1, except for initial run and backfilling efforts). 102 | createdTables := createdTables+1; 103 | END IF; 104 | 105 | startTime := intervalTime; 106 | 107 | END LOOP; 108 | 109 | -- The UNDEFINED_TABLE exception is captured on child table is created 'on-the-fly' when new data arrives and 110 | -- no partition is created to match this data criteria 111 | createTrigger := 'CREATE OR REPLACE FUNCTION '||schema_name||'.trf_'||primary_table_name||'_insert_trigger_function() 112 | RETURNS TRIGGER AS $$ 113 | DECLARE startTime timestamp; 114 | DECLARE intervalTime timestamp; 115 | DECLARE fullTablename text; 116 | DECLARE insertStatment text; 117 | DECLARE createTableStatment text; 118 | DECLARE formatDate text; 119 | BEGIN 120 | SELECT to_char('||date_expression||','''||dateFormat||''') INTO formatDate FROM (SELECT NEW.*) AS t; 121 | fullTablename := '''||primary_table_name||'_''||'||'formatDate; 122 | insertStatment := ''INSERT INTO '||schema_name||'.'''||'||fullTablename||'' VALUES ($1.*)''; 123 | BEGIN 124 | --Try insert on appropiatte child table if exists 125 | EXECUTE insertStatment using NEW; 126 | --When child tables not exists, generate it on the fly 127 | EXCEPTION WHEN UNDEFINED_TABLE THEN 128 | startTime := to_timestamp(formatDate, '''||dateFormat||'''); 129 | intervalTime := startTime + '''||spacing||'''::interval; 130 | 131 | createTableStatment := ''CREATE TABLE IF NOT EXISTS '||schema_name||'.''||fullTablename||'' ( 132 | CHECK ('||replace(date_expression, '''', '''''')||' >= ''''''||startTime||'''''' AND '||replace(date_expression, '''', '''''')||' < ''''''||intervalTime||'''''') 133 | ) INHERITS ('||schema_name||'.'||primary_table_name||')''; 134 | EXECUTE createTableStatment; 135 | 136 | createTableStatment := ''ALTER TABLE '||schema_name||'.''||fullTablename||'' OWNER TO "'||tableOwner||'";''; 137 | EXECUTE createTableStatment; 138 | 139 | createTableStatment := ''CREATE INDEX idx_''||fullTablename||''_'||dateColumnName||' ON '||schema_name||'.''||fullTablename||'' ('||replace(date_expression, '''', '''''')||');''; 140 | EXECUTE createTableStatment; 141 | 142 | --Try the insert again, now the table exists 143 | EXECUTE insertStatment using NEW; 144 | WHEN OTHERS THEN 145 | RAISE EXCEPTION ''Error in trigger''; 146 | RETURN NULL; 147 | END; 148 | RETURN NULL; 149 | END; 150 | $$ 151 | LANGUAGE plpgsql;'; 152 | 153 | EXECUTE createTrigger; 154 | 155 | -- Create the trigger that uses the trigger function, if it isn't already created 156 | triggerName := 'tr_'||primary_table_name||'_insert_trigger'; 157 | IF NOT EXISTS(SELECT * FROM information_schema.triggers WHERE trigger_name = triggerName) THEN 158 | createTrigger:='CREATE TRIGGER tr_'||primary_table_name||'_insert_trigger 159 | BEFORE INSERT ON '||schema_name||'.'||primary_table_name||' 160 | FOR EACH ROW EXECUTE PROCEDURE '||schema_name||'.trf_'||primary_table_name||'_insert_trigger_function();'; 161 | EXECUTE createTrigger; 162 | END IF; 163 | 164 | -- If truncate_parent_table parameter is true, we truncate only the parent table data AS this data is in child tables 165 | IF (truncate_parent_table) THEN 166 | RAISE NOTICE 'Truncate ONLY parent table %.%',schema_name,primary_table_name; 167 | insertStmts := 'TRUNCATE TABLE ONLY '||schema_name||'.'||primary_table_name||';'; 168 | EXECUTE insertStmts; 169 | END IF; 170 | 171 | RETURN createdTables; 172 | END; 173 | $BODY$ 174 | LANGUAGE plpgsql VOLATILE 175 | COST 100; 176 | ALTER FUNCTION public.create_date_partitions_for_table(timestamp without time zone, regclass, text, interval, boolean, boolean) 177 | OWNER TO postgres; 178 | COMMENT ON FUNCTION public.create_date_partitions_for_table(timestamp without time zone, regclass, text, interval, boolean, boolean) IS 'The function is created in the public schema and is owned by user postgres. 179 | The function takes params: 180 | begin_time - Type: timestamp - Desc: time of your earliest data. This allows for backfilling and for reducing trigger function overhead by avoiding legacy date logic. 181 | primary_table - Type: regclass - Desc: name of the parent table. This is used to generate monthly tables ([primary_table_name]_YYYYMM) and an unknown table ([primary_table_name]_unknowns). It is also used in the trigger and trigger function names. 182 | date_expression - Type: text - Desc: an expression that returns a date is used for check constraints and insert trigger function. 183 | spacing - Type: interval - Desc: an interval which determines the timespan for child tables 184 | fill_child_tables - Type: boolean - Desc: if you want to load data from parent table to each child tables. 185 | truncate_parent_table - Type: boolean - Desc: if you want to delete table of the parent table 186 | 187 | Considerations: 188 | 189 | - The insert trigger function is recreated everytime you run this function. 190 | 191 | - If child tables already exist, the function simply updates the trigger 192 | function and moves to the next table in the series. 193 | 194 | - This function does not raise exceptions when errant data is encountered. 195 | The trigger captures the UNDEFINED_TABLE exception when any data that does 196 | not have a matching child table and it automatically generates 197 | the appropiate child table and insert the row that generated the exeception. 198 | 199 | - The function returns the number of tables that it created. 200 | 201 | - The fill_child_tables and truncate_parent_table must be used carefully you may 202 | respald your parent table data before 203 | '; 204 | -------------------------------------------------------------------------------- /update_partitions_no_unknown_table_with_timezone.sql: -------------------------------------------------------------------------------- 1 | -- Function: public.create_date_partitions_for_table(timestamp without time zone, text, regclass, text, interval, boolean, boolean, text) 2 | -- DROP FUNCTION public.create_date_partitions_for_table(timestamp without time zone, text, regclass, text, interval, boolean, boolean, text); 3 | 4 | CREATE OR REPLACE FUNCTION public.create_date_partitions_for_table ( 5 | begin_time TIMESTAMP WITHOUT TIME ZONE, 6 | timezone TEXT, 7 | primary_table regclass, 8 | date_expression TEXT, 9 | spacing INTERVAL, 10 | fill_child_tables BOOLEAN, 11 | truncate_parent_table BOOLEAN 12 | ) RETURNS INTEGER AS $BODY$ 13 | 14 | DECLARE start_time TIMESTAMP; 15 | DECLARE end_time TIMESTAMP; 16 | DECLARE interval_time TIMESTAMP; 17 | DECLARE create_stmt TEXT; 18 | DECLARE insert_stmt TEXT; 19 | DECLARE create_trigger TEXT; 20 | DECLARE full_table_name TEXT; 21 | DECLARE my_trigger_name TEXT; 22 | DECLARE created_tables INTEGER; 23 | DECLARE interval_epoch INTEGER; 24 | DECLARE date_format TEXT; 25 | DECLARE date_column_name TEXT; 26 | DECLARE table_owner TEXT; 27 | DECLARE primary_table_name TEXT; 28 | DECLARE my_schema_name TEXT; 29 | 30 | 31 | BEGIN 32 | 33 | 34 | -- determine if the date_expression is a valid identifier 35 | CASE 36 | WHEN date_expression ~* '^[a-z0-9_$]+$' THEN 37 | date_column_name := date_expression; 38 | ELSE 39 | date_column_name := 'date'; 40 | END CASE; 41 | 42 | -- determine the date format for the given interval 43 | interval_epoch := EXTRACT (EPOCH FROM spacing); 44 | CASE 45 | WHEN interval_epoch < EXTRACT (EPOCH FROM INTERVAL '1 day') THEN 46 | date_format := 'error'; 47 | WHEN interval_epoch < EXTRACT (EPOCH FROM INTERVAL '1 week') THEN 48 | date_format := 'YYYYDDD'; 49 | WHEN interval_epoch < EXTRACT (EPOCH FROM INTERVAL '1 month') THEN 50 | date_format := 'IYYYIW'; 51 | WHEN interval_epoch < EXTRACT (EPOCH FROM INTERVAL '1 year') THEN 52 | date_format := 'YYYYMM'; 53 | ELSE 54 | date_format := 'YYYY'; 55 | END CASE; 56 | 57 | IF date_format = 'error' THEN 58 | RAISE EXCEPTION 'Interval must be greater than 1 day' ; 59 | END IF; 60 | 61 | -- get the table name, schema and owner 62 | SELECT 63 | c.relname, 64 | n.nspname, 65 | a.rolname INTO primary_table_name, 66 | my_schema_name, 67 | table_owner 68 | FROM 69 | pg_catalog.pg_class AS c 70 | JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid 71 | JOIN pg_catalog.pg_authid AS a ON c.relowner = a.oid 72 | WHERE 73 | c.oid = primary_table :: oid; 74 | 75 | -- Store the incoming begin_time, and set the end_time to one month/week/day in the future 76 | -- (this allows use of a cronjob at any time during the month/week/day to generate next month/week/day's table) 77 | start_time := to_timestamp(to_char(begin_time, date_format), date_format); 78 | end_time := to_timestamp(to_char(now() + spacing, date_format), date_format); 79 | created_tables := 0; 80 | 81 | WHILE (start_time <= end_time) LOOP 82 | 83 | full_table_name := primary_table_name || '_' || to_char(start_time, date_format); 84 | interval_time := start_time + spacing; 85 | 86 | -- The table creation sql statement 87 | IF NOT EXISTS (SELECT * FROM information_schema.tables WHERE table_schema = my_schema_name AND TABLE_NAME = full_table_name) THEN 88 | create_stmt := 89 | 'CREATE TABLE ' || my_schema_name || '.' || full_table_name || ' ( 90 | CHECK (' || date_expression || ' >= TIMESTAMP ''' || start_time || ''' AT TIME ZONE ''' || timezone || ''' 91 | AND ' || date_expression || ' < TIMESTAMP ''' || interval_time || ''' AT TIME ZONE ''' || timezone || ''') 92 | ) INHERITS (' || my_schema_name || '.' || primary_table_name || ')'; 93 | 94 | -- Run the table creation 95 | EXECUTE create_stmt; 96 | 97 | -- Set the table owner 98 | create_stmt := 'ALTER TABLE ' || my_schema_name || '.' || full_table_name || ' OWNER TO "' || table_owner || '";'; 99 | EXECUTE create_stmt; 100 | 101 | -- Create an index on the timestamp 102 | create_stmt := 'CREATE INDEX idx_' || full_table_name || '_' || date_column_name || ' ON ' || my_schema_name || '.' || full_table_name || ' (' || date_expression || ');'; 103 | EXECUTE create_stmt; 104 | RAISE NOTICE 'Child table %.% created', my_schema_name, full_table_name; 105 | 106 | --if fill_child_tables is true then we fill the child table with the parent's table data that satisfies the child's table check constraint 107 | IF (fill_child_tables) THEN 108 | RAISE NOTICE 'Filling child table %.%', my_schema_name, full_table_name; 109 | insert_stmt := 110 | 'INSERT INTO ' || my_schema_name || '.' || full_table_name || ' ( 111 | SELECT * FROM ' || my_schema_name || '.' || primary_table_name || ' 112 | WHERE ' || date_expression || ' AT TIME ZONE ''' || timezone || ''' >= ''' || start_time || ''' 113 | AND ' || date_expression || ' AT TIME ZONE ''' || timezone || ''' < ''' || interval_time || ''' 114 | );'; 115 | EXECUTE insert_stmt ; 116 | END IF; 117 | 118 | -- Track how many tables we are creating (should likely be 1, except for initial run and backfilling efforts). 119 | created_tables := created_tables + 1; 120 | END IF; 121 | 122 | start_time := interval_time; 123 | 124 | END LOOP; 125 | 126 | -- The UNDEFINED_TABLE exception is captured on child table is created 'on-the-fly' when new data arrives and 127 | -- no partition is created to match this data criteria 128 | create_trigger := 129 | 'CREATE OR REPLACE FUNCTION ' || my_schema_name || '.trf_' || primary_table_name || '_insert_trigger_function() RETURNS TRIGGER AS $$ 130 | 131 | DECLARE start_time timestamp; 132 | DECLARE timezone text; 133 | DECLARE interval_time timestamp; 134 | DECLARE full_table_name text; 135 | DECLARE insertStatment text; 136 | DECLARE createTableStatment text; 137 | DECLARE formatDate text; 138 | 139 | BEGIN 140 | 141 | SELECT to_char(' || date_expression || ',''' || date_format || ''') INTO formatDate FROM (SELECT NEW.*) AS t; 142 | full_table_name := ''' || primary_table_name || '_''||' || 'formatDate; 143 | insertStatment := ''INSERT INTO ' || my_schema_name || '.''' || '||full_table_name||'' VALUES ($1.*)''; 144 | timezone := ''' || timezone || '''; 145 | 146 | BEGIN 147 | 148 | --Try insert on appropiatte child table if exists 149 | EXECUTE insertStatment using NEW; 150 | 151 | --When child tables not exists, generate it on the fly 152 | EXCEPTION WHEN UNDEFINED_TABLE THEN 153 | start_time := to_timestamp(formatDate, ''' || date_format || '''); 154 | interval_time := start_time + ''' || spacing || '''::interval; 155 | 156 | createTableStatment := ''CREATE TABLE IF NOT EXISTS ' || my_schema_name || '.''||full_table_name||'' ( 157 | CHECK (' || REPLACE (date_expression, '''', '''''') || ' >= TIMESTAMP ''''''||start_time||'''''' AT TIME ZONE ''''''||timezone||'''''' 158 | AND ' || REPLACE (date_expression, '''', '''''') || ' < TIMESTAMP ''''''||interval_time||'''''' AT TIME ZONE ''''''||timezone||'''''')) 159 | INHERITS (' || my_schema_name || '.' || primary_table_name || ')''; 160 | EXECUTE createTableStatment; 161 | 162 | createTableStatment := ''ALTER TABLE ' || my_schema_name || '.''||full_table_name||'' OWNER TO "' || table_owner || '";''; 163 | EXECUTE createTableStatment; 164 | 165 | createTableStatment := ''CREATE INDEX idx_''||full_table_name||''_' || date_column_name || ' ON ' || my_schema_name || '.''||full_table_name||'' 166 | (' || REPLACE (date_expression, '''', '''''') || ');''; 167 | EXECUTE createTableStatment; 168 | 169 | --Try the insert again, now the table exists 170 | EXECUTE insertStatment using NEW; 171 | 172 | WHEN OTHERS THEN 173 | RAISE EXCEPTION ''Error in trigger''; 174 | 175 | RETURN NULL; 176 | 177 | END; 178 | 179 | RETURN NULL; 180 | 181 | END; 182 | 183 | $$ LANGUAGE plpgsql;'; 184 | EXECUTE create_trigger ; 185 | 186 | -- Create the trigger that uses the trigger function, if it isn't already created 187 | my_trigger_name := 'tr_' || primary_table_name || '_insert_trigger'; 188 | 189 | IF NOT EXISTS (SELECT * FROM information_schema.triggers WHERE TRIGGER_NAME = my_trigger_name) THEN 190 | create_trigger := 191 | 'CREATE TRIGGER tr_' || primary_table_name || '_insert_trigger 192 | BEFORE INSERT ON ' || my_schema_name || '.' || primary_table_name || ' 193 | FOR EACH ROW EXECUTE PROCEDURE ' || my_schema_name || '.trf_' || primary_table_name || '_insert_trigger_function();'; 194 | EXECUTE create_trigger; 195 | END IF; 196 | 197 | -- If truncate_parent_table parameter is true, we truncate only the parent table data AS this data is in child tables 198 | IF (truncate_parent_table) THEN 199 | RAISE NOTICE 'Truncate ONLY parent table %.%', my_schema_name, primary_table_name; 200 | insert_stmt := 'TRUNCATE TABLE ONLY ' || my_schema_name || '.' || primary_table_name || ';'; 201 | EXECUTE insert_stmt; 202 | END IF; 203 | 204 | RETURN created_tables; 205 | 206 | 207 | END; 208 | 209 | 210 | $BODY$ LANGUAGE plpgsql VOLATILE COST 100; 211 | 212 | ALTER FUNCTION public.create_date_partitions_for_table ( 213 | TIMESTAMP WITHOUT TIME ZONE, 214 | TEXT, 215 | regclass, 216 | TEXT, 217 | INTERVAL, 218 | BOOLEAN, 219 | BOOLEAN 220 | ) OWNER TO postgres; 221 | 222 | COMMENT ON FUNCTION public.create_date_partitions_for_table ( 223 | TIMESTAMP WITHOUT TIME ZONE, 224 | TEXT, 225 | regclass, 226 | TEXT, 227 | INTERVAL, 228 | BOOLEAN, 229 | BOOLEAN 230 | ) IS 231 | 'The function is created in the public schema and is owned by user postgres. 232 | The function takes params: 233 | begin_time 234 | - Type: timestamp 235 | - Desc: time of your earliest data. This allows for backfilling and for reducing trigger function overhead by avoiding legacy date logic. 236 | timezone 237 | - Type: text 238 | - Desc: time zone for check constraints. Available time zones in pg_timezone_names table. 239 | primary_table 240 | - Type: regclass 241 | - Desc: name of the parent table. This is used to generate monthly tables ([primary_table_name]_YYYYMM) and an unknown table ([primary_table_name]_unknowns). It is also used in the trigger and trigger function names. 242 | date_expression 243 | - Type: text 244 | - Desc: an expression that returns a date is used for check constraints and insert trigger function. 245 | spacing 246 | - Type: interval 247 | - Desc: an interval which determines the timespan for child tables. 248 | fill_child_tables 249 | - Type: boolean 250 | - Desc: if you want to load data from parent table to each child tables. 251 | truncate_parent_table 252 | - Type: boolean 253 | - Desc: if you want to delete table of the parent table. 254 | 255 | Considerations: 256 | 257 | - The insert trigger function is recreated everytime you run this function. 258 | 259 | - If child tables already exist, the function simply updates the trigger function and moves to the next table in the series. 260 | 261 | - This function does not raise exceptions when errant data is encountered. The trigger captures the UNDEFINED_TABLE exception when any data that does not have a matching child table and it automatically generates the appropiate child table and insert the row that generated the exeception. 262 | 263 | - The function returns the number of tables that it created. 264 | 265 | - The fill_child_tables and truncate_parent_table must be used carefully you may respald your parent table data before.'; 266 | --------------------------------------------------------------------------------