Re: Default for date field: today vs CURRENT_DATE

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Rich Shepard <rshepard(at)appl-ecosys(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Default for date field: today vs CURRENT_DATE
Date: 2019-01-02 22:01:14
Message-ID: 10029.1546466474@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Rich Shepard <rshepard(at)appl-ecosys(dot)com> writes:
> Reading the manual I saw that 'today' is a special value, but it did not
> work when I used it as a column default; e.g.,
> start_date date DEFAULT today,
> Appending parentheses also failed. But, changing today to CURRENT_DATE
> worked. I've not found an explanation and would appreciate learning why
> 'today' fails.

'today' is special as a date input string, so you can use it as a literal:

regression=# select 'today'::date;
date
------------
2019-01-02
(1 row)

But it's not a SQL keyword, nor a function name, so you can't write it
without quotes.

Also, it wouldn't be very useful for this purpose, because it's resolved
on sight in date_in(). Thus

regression=# create table wrong_thing (start_date date DEFAULT 'today');
CREATE TABLE
regression=# \d wrong_thing
Table "public.wrong_thing"
Column | Type | Collation | Nullable | Default
------------+------+-----------+----------+--------------------
start_date | date | | | '2019-01-02'::date

The default would effectively be the creation date of the table,
not the insertion date of any particular row.

So CURRENT_DATE or one of its sibling functions is what you want
here. On the other hand, something like

INSERT INTO my_table VALUES ('today', ...);

might be perfectly sensible code.

regards, tom lane

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Rich Shepard 2019-01-02 22:12:42 Re: Default for date field: today vs CURRENT_DATE [RESOLVED]
Previous Message Rich Shepard 2019-01-02 21:49:21 Default for date field: today vs CURRENT_DATE