|
| 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 | +$$; |
0 commit comments