Thread: Get the difference between two timestamp cells but in a special format in PostgreSQL
Get the difference between two timestamp cells but in a special format in PostgreSQL
From
litu16
Date:
This is my table... <http://postgresql.nabble.com/file/n5855074/screenshot.jpg> I would like to get the time difference between 'time_type = Lap' AND 'time_type = Start' in order to fill 'time_elapse'. Im almost sure that this code works... * CREATE OR REPLACE FUNCTION timediff() RETURNS trigger AS $BODY$ DECLARE t_ix real; BEGIN IF NEW.time_type = 'Lap' THEN SELECT t.time FROM table_ebscb_spa_log04 t WHERE t.fn_name = NEW.fn_name AND t.time_type = 'Start' ORDER BY t.stmtserial DESC LIMIT 1 INTO t_ix; IF NOT FOUND THEN RAISE EXCEPTION USING MESSAGE = 'There is not any previous row...'; ELSE NEW.time_elapse := t_ix - NEW.time; END IF; END IF; return NEW; END $BODY$ LANGUAGE plpgsql VOLATILE* But I don't know how to get the time difference between the two timestamps cells in a special format: (years/months/days hours:minutes:seconds:miliseconds) like this... * 0y/0m/0d 00:00:01.001* Is this possible?? Thanks Advanced. -- View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074.html Sent from the PostgreSQL - general mailing list archive at Nabble.com.
Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
Colin Lieberman
Date:
You may be looking for to_char:
# select to_char( now() - '2015-06-25', 'YYYY-MM-DD HH24:mm:ss' );
to_char
---------------------
0000-00-00 15:00:43
(1 row)
On Wed, Jun 24, 2015 at 9:11 PM, litu16 <litumelendez@gmail.com> wrote:
This is my table...
<http://postgresql.nabble.com/file/n5855074/screenshot.jpg>
I would like to get the time difference between 'time_type = Lap' AND
'time_type = Start' in order to fill 'time_elapse'. Im almost sure that this
code works...
* CREATE OR REPLACE FUNCTION timediff()
RETURNS trigger AS
$BODY$
DECLARE
t_ix real;
BEGIN
IF NEW.time_type = 'Lap' THEN
SELECT t.time FROM table_ebscb_spa_log04 t WHERE t.fn_name =
NEW.fn_name AND t.time_type = 'Start' ORDER BY t.stmtserial DESC LIMIT 1
INTO t_ix;
IF NOT FOUND THEN
RAISE EXCEPTION USING MESSAGE = 'There is not any previous
row...';
ELSE
NEW.time_elapse := t_ix - NEW.time;
END IF;
END IF;
return NEW;
END
$BODY$
LANGUAGE plpgsql VOLATILE*
But I don't know how to get the time difference between the two timestamps
cells in a special format: (years/months/days
hours:minutes:seconds:miliseconds) like this...
* 0y/0m/0d 00:00:01.001*
Is this possible??
Thanks Advanced.
--
View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074.html
Sent from the PostgreSQL - general mailing list archive at Nabble.com.
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
Colin Lieberman
Date:
(But don't use my format string, it's very wrong!)
On Thu, Jun 25, 2015 at 3:20 PM, Colin Lieberman <clieberman@turnitin.com> wrote:
You may be looking for to_char:# select to_char( now() - '2015-06-25', 'YYYY-MM-DD HH24:mm:ss' );to_char---------------------0000-00-00 15:00:43(1 row)On Wed, Jun 24, 2015 at 9:11 PM, litu16 <litumelendez@gmail.com> wrote:This is my table...
<http://postgresql.nabble.com/file/n5855074/screenshot.jpg>
I would like to get the time difference between 'time_type = Lap' AND
'time_type = Start' in order to fill 'time_elapse'. Im almost sure that this
code works...
* CREATE OR REPLACE FUNCTION timediff()
RETURNS trigger AS
$BODY$
DECLARE
t_ix real;
BEGIN
IF NEW.time_type = 'Lap' THEN
SELECT t.time FROM table_ebscb_spa_log04 t WHERE t.fn_name =
NEW.fn_name AND t.time_type = 'Start' ORDER BY t.stmtserial DESC LIMIT 1
INTO t_ix;
IF NOT FOUND THEN
RAISE EXCEPTION USING MESSAGE = 'There is not any previous
row...';
ELSE
NEW.time_elapse := t_ix - NEW.time;
END IF;
END IF;
return NEW;
END
$BODY$
LANGUAGE plpgsql VOLATILE*
But I don't know how to get the time difference between the two timestamps
cells in a special format: (years/months/days
hours:minutes:seconds:miliseconds) like this...
* 0y/0m/0d 00:00:01.001*
Is this possible??
Thanks Advanced.
--
View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074.html
Sent from the PostgreSQL - general mailing list archive at Nabble.com.
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
Adrian Klaver
Date:
On 06/24/2015 09:11 PM, litu16 wrote: > This is my table... > > <http://postgresql.nabble.com/file/n5855074/screenshot.jpg> > > I would like to get the time difference between 'time_type = Lap' AND > 'time_type = Start' in order to fill 'time_elapse'. Im almost sure that this > code works... > > * CREATE OR REPLACE FUNCTION timediff() > RETURNS trigger AS > $BODY$ > DECLARE > t_ix real; > > BEGIN > IF NEW.time_type = 'Lap' THEN > SELECT t.time FROM table_ebscb_spa_log04 t WHERE t.fn_name = > NEW.fn_name AND t.time_type = 'Start' ORDER BY t.stmtserial DESC LIMIT 1 > INTO t_ix; > IF NOT FOUND THEN > RAISE EXCEPTION USING MESSAGE = 'There is not any previous > row...'; > ELSE > NEW.time_elapse := t_ix - NEW.time; > END IF; > END IF; > return NEW; > END > $BODY$ > LANGUAGE plpgsql VOLATILE* > > But I don't know how to get the time difference between the two timestamps > cells in a special format: (years/months/days > hours:minutes:seconds:miliseconds) like this... Well subtracting two timestamps gets you an interval: http://www.postgresql.org/docs/9.4/interactive/functions-datetime.html Table 9-27. Date/Time Operators which you can convert: http://www.postgresql.org/docs/9.4/interactive/functions-formatting.html to_char(interval, text) text convert interval to string to_char(interval '15h 2m 12s', 'HH24:MI:SS') so: postgres@production=# SELECT to_char(interval '15h 2m 12s', 'HH24:MI:SS'); to_char ---------- 15:02:12 (1 row) > > * 0y/0m/0d 00:00:01.001* > > Is this possible?? > Thanks Advanced. > > > > -- > View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074.html > Sent from the PostgreSQL - general mailing list archive at Nabble.com. > > -- Adrian Klaver adrian.klaver@aklaver.com
Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
litu16
Date:
Hi Adrian, but I would like to get the time diff in this format 0years 0months 0days 00:00:00.000 not only hours, minutes, seconds. is this possible??? Thanks Advanced. -- View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074p5855215.html Sent from the PostgreSQL - general mailing list archive at Nabble.com.
Re: Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
Adrian Klaver
Date:
On 06/25/2015 08:23 PM, litu16 wrote: > Hi Adrian, > > but I would like to get the time diff in this format > > 0years 0months 0days 00:00:00.000 > > not only hours, minutes, seconds. > > is this possible??? Well age: http://www.postgresql.org/docs/9.4/interactive/functions-datetime.html does that sort of: production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2015-06-26 02:16:00'); age ---------- 06:59:15 (1 row) production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2015-06-20 02:16:00'); age ----------------- 6 days 06:59:15 (1 row) production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2014-06-20 02:16:00'); age ------------------------ 1 year 6 days 06:59:15 (1 row) > > Thanks Advanced. > > > > -- > View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074p5855215.html > Sent from the PostgreSQL - general mailing list archive at Nabble.com. > > -- Adrian Klaver adrian.klaver@aklaver.com
Re: Re: Get the difference between two timestamp cells but in a special format in PostgreSQL
From
Colin Lieberman
Date:
Check the formatting functions documentation: http://www.postgresql.org/docs/9.4/static/functions-formatting.html
# select to_char( now() - '2015-06-27 14:33:24'
, 'Y"years" MM"months" DD"days" HH:MI:SS"."MS' );
to_char
-------------------------------------
0years 00months 01days 06:24:59.381
(1 row)
On Fri, Jun 26, 2015 at 10:52 AM, Adrian Klaver <adrian.klaver@aklaver.com> wrote:
On 06/25/2015 08:23 PM, litu16 wrote:Hi Adrian,
but I would like to get the time diff in this format
0years 0months 0days 00:00:00.000
not only hours, minutes, seconds.
is this possible???
Well age:
http://www.postgresql.org/docs/9.4/interactive/functions-datetime.html
does that sort of:
production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2015-06-26 02:16:00');
age
----------
06:59:15
(1 row)
production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2015-06-20 02:16:00');
age
-----------------
6 days 06:59:15
(1 row)
production=# SELECT age(timestamp '2015-06-26 09:15:15', timestamp '2014-06-20 02:16:00');
age
------------------------
1 year 6 days 06:59:15
(1 row)
Thanks Advanced.
--
View this message in context: http://postgresql.nabble.com/Get-the-difference-between-two-timestamp-cells-but-in-a-special-format-in-PostgreSQL-tp5855074p5855215.html
Sent from the PostgreSQL - general mailing list archive at Nabble.com.
--
Adrian Klaver
adrian.klaver@aklaver.com
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general