Обсуждение: Adding timestamp column
Hi admins, greetings.
I'm trying to add a timestamp column in an existent table.
This query works fine:
select timecreated, timezone('America/Santiago'::text, to_timestamp(timecreated::double precision)) datecreated
from MDL_LOGSTORE_STANDARD_LOG;
This query works fine:
select timecreated, timezone('America/Santiago'::text, to_timestamp(timecreated::double precision)) datecreated
from MDL_LOGSTORE_STANDARD_LOG;
But, when I want to alter the table I get a syntax error
alter table MDL_LOGSTORE_STANDARD_LOG
add column datecreated timestamp
generated always as ( timezone ('America/Santiago'::text, to_timestamp(timecreated::double precision)));
add column datecreated timestamp
generated always as ( timezone ('America/Santiago'::text, to_timestamp(timecreated::double precision)));
SQL Error [42601]: ERROR: syntax error at end of input
Position: 185
Position: 185
I would appreciate some tips
Thanks in advanced
kind regards
Mauricio Fernández
On Wednesday, September 3, 2025, Mauricio Fernandez <mmauricio.fernandez@gmail.com> wrote:
But, when I want to alter the table I get a syntax erroralter table MDL_LOGSTORE_STANDARD_LOG
add column datecreated timestamp
generated always as ( timezone ('America/Santiago'::text, to_timestamp(timecreated::double precision))); SQL Error [42601]: ERROR: syntax error at end of input
Position: 185
Unless you are experimenting with v18 the docs clearly indicate the keyword “stored” is mandatory (since the implemented in 18 virtual is the default).
David J.
Am 03.09.25 um 17:50 schrieb Mauricio Fernandez: > Hi admins, greetings. > > I'm trying to add a timestamp column in an existent table. > > This query works fine: > > select timecreated, timezone('America/Santiago'::text, > to_timestamp(timecreated::double precision)) datecreated > from MDL_LOGSTORE_STANDARD_LOG; > > But, when I want to alter the table I get a syntax error > > alter table MDL_LOGSTORE_STANDARD_LOG > add column datecreated timestamp > generated always as ( timezone ('America/Santiago'::text, > to_timestamp(timecreated::double precision))); > > SQL Error [42601]: ERROR: syntax error at end of input > Position: 185 > > I would appreciate some tips > > Thanks in advanced > > kind regards > > Mauricio Fernández Instead of alter table MDL_LOGSTORE_STANDARD_LOG add column datecreated timestamp generated always as ( timezone ('America/Santiago'::text, to_timestamp(timecreated::double precision))); I would suggest ALTER TABLE MDL_LOGSTORE_STANDARD_LOG ADD COLUMN datecreated TIMESTAMP GENERATED ALWAYS AS (timecreated AT TIME ZONE 'America/Santiago') STORED; You didn't tell us the data type of the column timecreated. It should be 'TIMESTAMPTZ DEFAULT current_timestamp' for it to work properly. As of Version 18 you can leave out STORED, creating a virtual generated column. Kind Regards, Holger -- Holger Jakobs, Bergisch Gladbach
Thank you Holger and David, the error was the missing clausule STORED
The timecreated data type is Int8
King regards
Mauricio Fernández
El mié, 3 sept 2025 a las 13:46, Holger Jakobs (<holger@jakobs.com>) escribió:
Am 03.09.25 um 17:50 schrieb Mauricio Fernandez:
> Hi admins, greetings.
>
> I'm trying to add a timestamp column in an existent table.
>
> This query works fine:
>
> select timecreated, timezone('America/Santiago'::text,
> to_timestamp(timecreated::double precision)) datecreated
> from MDL_LOGSTORE_STANDARD_LOG;
>
> But, when I want to alter the table I get a syntax error
>
> alter table MDL_LOGSTORE_STANDARD_LOG
> add column datecreated timestamp
> generated always as ( timezone ('America/Santiago'::text,
> to_timestamp(timecreated::double precision)));
>
> SQL Error [42601]: ERROR: syntax error at end of input
> Position: 185
>
> I would appreciate some tips
>
> Thanks in advanced
>
> kind regards
>
> Mauricio Fernández
Instead of
alter table MDL_LOGSTORE_STANDARD_LOG
add column datecreated timestamp
generated always as ( timezone ('America/Santiago'::text,
to_timestamp(timecreated::double precision)));
I would suggest
ALTER TABLE MDL_LOGSTORE_STANDARD_LOG
ADD COLUMN datecreated TIMESTAMP
GENERATED ALWAYS AS (timecreated AT TIME ZONE 'America/Santiago') STORED;
You didn't tell us the data type of the column timecreated. It should be
'TIMESTAMPTZ DEFAULT current_timestamp' for it to work properly.
As of Version 18 you can leave out STORED, creating a virtual generated
column.
Kind Regards,
Holger
--
Holger Jakobs, Bergisch Gladbach