From: | Holger Jakobs <holger(at)jakobs(dot)com> |
---|---|
To: | pgsql-admin(at)lists(dot)postgresql(dot)org |
Subject: | Re: Adding timestamp column |
Date: | 2025-09-03 17:46:16 |
Message-ID: | 2aa85cf2-dfb1-474e-b190-0a96d7afeb2b@jakobs.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-admin |
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
From | Date | Subject | |
---|---|---|---|
Next Message | Mauricio Fernandez | 2025-09-03 17:51:19 | Re: Adding timestamp column |
Previous Message | David G. Johnston | 2025-09-03 16:09:07 | Re: Adding timestamp column |