DROP FUNCTION IF EXISTS public.get_query_partitioning_of_an_existing_table_by_date_unix_time(text, text, integer, integer, text); CREATE OR REPLACE FUNCTION public.get_query_partitioning_of_an_existing_table_by_date_unix_time( old_tablename text, new_tablename text, start_year integer, end_year integer, step text) RETURNS character varying LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE AS $BODY$ DECLARE partition_tablename TEXT; start_interval TEXT; end_interval TEXT; i INTEGER; sql_str TEXT; start_unix_time TEXT; end_unix_time TEXT; BEGIN IF start_year > end_year THEN RAISE NOTICE '%', 'start_year > end_year'; RETURN ''; END IF; WHILE start_year <= end_year LOOP -- loop through years -- set the initial month CASE step WHEN 'monthly' THEN i:= 1; WHEN 'quaterly' THEN i:= 3; WHEN 'half-yearly' THEN i:= 6; WHEN 'yearly' THEN i:= 12; ELSE RAISE NOTICE '%', 'Invalid step parameter. Valid values are : monthly, quaterly, half-yearly, yearly'; EXIT; END CASE; WHILE i <= 12 LOOP -- loop through month partition_tablename := ''; CASE step WHEN 'monthly' THEN partition_tablename := old_tablename || '_' || lpad(i::text, 2, '0') || '_' || start_year::text; start_interval = start_year::text || '-' || lpad(i::text, 2, '0') || '-01'; end_interval = (date_trunc('month', start_interval::date) + interval '1 months')::date; i := i + 1; start_unix_time = extract(epoch from (start_interval)::timestamp); end_unix_time = extract(epoch from (end_interval::date - Interval'1 sec')::timestamp); WHEN 'quaterly' THEN IF (i % 3 = 0) THEN partition_tablename := old_tablename || '_Q' || i/3 || '_' || start_year::text; start_interval = start_year::text || '-' || case i/3 when 1 then '01-01' when 2 then '04-01' when 3 then '07-01' when 4 then '10-01' end; end_interval = (date_trunc('quarter', start_interval::date) + interval '3 months')::date; i := i + 3; start_unix_time = extract(epoch from (start_interval)::timestamp); end_unix_time = extract(epoch from (end_interval::date - Interval'1 sec')::timestamp); END IF; WHEN 'half-yearly' THEN IF (i % 6 = 0) THEN partition_tablename := old_tablename || '_S' || i/6 || '_' || start_year::text; start_interval = start_year::text || case i/6 when 1 then '-01-01' else '-07-01' end ; end_interval = (start_interval::date + interval '6 months')::date; i := i + 6; start_unix_time = extract(epoch from (start_interval)::timestamp); end_unix_time = extract(epoch from (end_interval::date - Interval'1 sec')::timestamp); END IF; WHEN 'yearly' THEN IF (i % 12 = 0) THEN partition_tablename := old_tablename || '_' || start_year::text; start_interval = start_year::text || '-01-01'; end_interval = (date_trunc('year', start_interval::date) + interval '1 year')::date; i := i + 12; start_unix_time = extract(epoch from (start_interval)::timestamp); end_unix_time = extract(epoch from (end_interval::date - Interval'1 sec')::timestamp); END IF; ELSE RAISE NOTICE '%', 'Invalid step parameter. Valid values are : monthly, quaterly, half-yearly, yearly'; EXIT; END CASE; IF ( partition_tablename <> '') THEN sql_str := COALESCE(sql_str, '') || CHR(13) || 'CREATE TABLE ' || partition_tablename || ' PARTITION OF ' || new_tablename || ' FOR VALUES FROM (' || start_unix_time || ') TO (' || end_unix_time || ');'; END IF; END LOOP; start_year := start_year + 1; sql_str := COALESCE(sql_str, '') || CHR(13); END LOOP; --RAISE NOTICE '%', sql_str; RETURN COALESCE(sql_str, ''); END; $BODY$;