I ran into the same problem, and the solution I adopted was to create a composite type like "birthday" with the "day" and "month" columns as integers:
CREATE TYPE birthday AS (
day integer,
month integer
);
This way you can use literals like '(02,29)'::birthday
. (I know it's not ideal).
We still have the validation problem, so my solution was to create a DOMAIN that performed this verification:
CREATE OR REPLACE FUNCTION public.check_birthday(
birthday birthday)
RETURNS boolean
LANGUAGE 'plpgsql'
IMMUTABLE LEAKPROOF PARALLEL SAFE
AS $BODY$
DECLARE
valid_date date;
BEGIN
valid_date := MAKE_DATE(
2000, -- arbitrary leap year
birthday.month,
birthday.day
);
RETURN TRUE;
EXCEPTION
WHEN datetime_field_overflow
THEN RETURN FALSE;
END;
$BODY$;
CREATE DOMAIN public.valid_birthday
AS birthday CHECK (check_birthday(VALUE));
And optionally you can also create a Postgres CAST to simplify the conversion to DATE and vice versa:
CREATE OR REPLACE FUNCTION public.to_date(
birthday birthday,
year integer
)
RETURNS date
LANGUAGE 'plpgsql'
IMMUTABLE LEAKPROOF PARALLEL SAFE
AS $BODY$
BEGIN
IF birthday.month = 2 and birthday.day = 29 THEN -- The leap year day exception case
RETURN MAKE_DATE(year,3,1) - '1 day'::interval; -- Returns the date before 03/01 of given year
ELSE
RETURN MAKE_DATE(
year,
birthday.month,
birthday.day
);
END IF;
END;
$BODY$;
CREATE OR REPLACE FUNCTION public.to_date(birthday birthday)
RETURNS date LANGUAGE 'sql' IMMUTABLE LEAKPROOF PARALLEL SAFE
AS $$
SELECT to_date(
birthday,
extract(year from now())::integer
)
$$;
CREATE CAST (birthday AS date)
WITH FUNCTION public.to_date(birthday)
AS IMPLICIT;
SELECT '(02,29)'::birthday::date; -- 2024-02-29
SELECT to_date('(02,29)'::birthday, 2023); -- 2023-02-28
SELECT your_birthday_column::date FROM your_table; -- Same effect
CREATE OR REPLACE FUNCTION public.to_birthday(birthdate date)
RETURNS birthday LANGUAGE 'sql' IMMUTABLE LEAKPROOF PARALLEL SAFE
AS $$
SELECT row(
extract(month from birthdate)::integer,
extract(day from birthdate)::integer
)::birthday
$$;
CREATE CAST (date AS birthday)
WITH FUNCTION public.to_birthday(date )
AS IMPLICIT;
SELECT '2024-02-29'::date::birthday; -- (02/29);
I know that this solution is very verbose and has a lot of low code, but for use in my implementations it was ideal and very robust. I hope it helps you :)