Doc: caution against misuse of 'now' and related datetime literals.

Section 8.5.1.4, which defines these literals, made only a vague
reference to the fact that they might be evaluated too soon to be
safe in non-interactive contexts.  Provide a more explicit caution
against misuse.  Also, generalize the wording in the related tip in
section 9.9.4: while it clearly described this problem, it implied
(or really, stated outright) that the problem only applies to table
DEFAULT clauses.

Per gripe from Tijs van Dam.  Back-patch to all supported branches.

Discussion: https://postgr.es/m/c2LuRv9BiRT3bqIo5mMQiVraEXey_25B4vUn0kDqVqilwOEu_iVF1tbtvLnyQK7yDG3PFaz_GxLLPil2SDkj1MCObNRVaac-7j1dVdFERk8=@thalex.com
This commit is contained in:
Tom Lane 2020-10-17 16:02:47 -04:00
parent 2b9166dbc6
commit 133d06f7bb
2 changed files with 22 additions and 6 deletions

View File

@ -2103,7 +2103,7 @@ January 8 04:05:06 1999 PST
</para>
</sect3>
<sect3>
<sect3 id="datatype-datetime-special-values">
<title>Special Values</title>
<indexterm>
@ -2191,12 +2191,26 @@ January 8 04:05:06 1999 PST
type:
<literal>CURRENT_DATE</literal>, <literal>CURRENT_TIME</literal>,
<literal>CURRENT_TIMESTAMP</literal>, <literal>LOCALTIME</literal>,
<literal>LOCALTIMESTAMP</literal>. The latter four accept an
optional subsecond precision specification. (See <xref
<literal>LOCALTIMESTAMP</literal>. (See <xref
linkend="functions-datetime-current"/>.) Note that these are
SQL functions and are <emphasis>not</emphasis> recognized in data input strings.
</para>
<caution>
<para>
While the input strings <literal>now</literal>,
<literal>today</literal>, <literal>tomorrow</literal>,
and <literal>yesterday</literal> are fine to use in interactive SQL
commands, they can have surprising behavior when the command is
saved to be executed later, for example in prepared statements,
views, and function definitions. The string can be converted to a
specific time value that continues to be used long after it becomes
stale. Use one of the SQL functions instead in such contexts.
For example, <literal>CURRENT_DATE + 1</literal> is safer than
<literal>'tomorrow'::date</literal>.
</para>
</caution>
</sect3>
</sect2>

View File

@ -8340,20 +8340,22 @@ now()
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now'; -- incorrect for use with DEFAULT
SELECT TIMESTAMP 'now'; -- but see tip below
</programlisting>
</para>
<tip>
<para>
You do not want to use the third form when specifying a <literal>DEFAULT</literal>
clause while creating a table. The system will convert <literal>now</literal>
Do not use the third form when specifying a value to be evaluated later,
for example in a <literal>DEFAULT</literal> clause for a table column.
The system will convert <literal>now</literal>
to a <type>timestamp</type> as soon as the constant is parsed, so that when
the default value is needed,
the time of the table creation would be used! The first two
forms will not be evaluated until the default value is used,
because they are function calls. Thus they will give the desired
behavior of defaulting to the time of row insertion.
(See also <xref linkend="datatype-datetime-special-values"/>.)
</para>
</tip>
</sect2>