Обсуждение: Please help me write a query

Поиск
Список
Период
Сортировка

Please help me write a query

От
Nikolas Everett
Дата:
Say I have a table that stores state transitions over time like so:
id, transitionable_id, state1, state2, timestamp

I'm trying to write a query that coalesces changes in state2 away to produce just a list of transitions of state1.  I guess it would look something like

SELECT state1, FIRST(timestamp)
FROM table

but I have no idea how to aggregate just the repeated state1 rows.

Re: Please help me write a query

От
Ozz Nixon
Дата:
Lost me a bit, do you mean DISTINCT?

select distinct state1, first(timestamp) from table????

On May 27, 2010, at 10:04 AM, Nikolas Everett wrote:

> Say I have a table that stores state transitions over time like so:
> id, transitionable_id, state1, state2, timestamp
>
> I'm trying to write a query that coalesces changes in state2 away to produce just a list of transitions of state1.  I
guessit would look something like 
>
> SELECT state1, FIRST(timestamp)
> FROM table
>
> but I have no idea how to aggregate just the repeated state1 rows.


Re: Please help me write a query

От
Nikolas Everett
Дата:
Sorry.  Here is the setup:
CREATE TABLE test (id BIGSERIAL PRIMARY KEY, state1 INT NOT NULL, state2 INT NOT NULL, timestamp TIMESTAMP);
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '12 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 2, now() - interval '11 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '10 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (2, 1, now() - interval '9 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '8 hours');


I want to write a query that spits out:
 state1 |         timestamp          
--------+----------------------------
      1 | now() - interval '12 hours'
      2 | now() - interval '9 hours'
      1 | now() - interval '8 hours'

Standard grouping destroys the third row so that's out.  No grouping at all gives repeats of state1.  Is this what partitioning is for?

Nik

On Thu, May 27, 2010 at 10:20 AM, Ozz Nixon <ozznixon@gmail.com> wrote:
Lost me a bit, do you mean DISTINCT?

select distinct state1, first(timestamp) from table????

On May 27, 2010, at 10:04 AM, Nikolas Everett wrote:

> Say I have a table that stores state transitions over time like so:
> id, transitionable_id, state1, state2, timestamp
>
> I'm trying to write a query that coalesces changes in state2 away to produce just a list of transitions of state1.  I guess it would look something like
>
> SELECT state1, FIRST(timestamp)
> FROM table
>
> but I have no idea how to aggregate just the repeated state1 rows.


Re: Please help me write a query

От
Justin Graf
Дата:
On 5/27/2010 9:04 AM, Nikolas Everett wrote:
> Say I have a table that stores state transitions over time like so:
> id, transitionable_id, state1, state2, timestamp
>
> I'm trying to write a query that coalesces changes in state2 away to
> produce just a list of transitions of state1.  I guess it would look
> something like
>
> SELECT state1, FIRST(timestamp)
> FROM table
>
> but I have no idea how to aggregate just the repeated state1 rows.

if i understand what your  after

Select distinct transitinable_id, state1,  min(timestamp) from table
group by  transitinable_id, state1















All legitimate Magwerks Corporation quotations are sent in a .PDF file attachment with a unique ID number generated by
ourproprietary quotation system. Quotations received via any other form of communication will not be honored. 

CONFIDENTIALITY NOTICE: This e-mail, including attachments, may contain legally privileged, confidential or other
informationproprietary to Magwerks Corporation and is intended solely for the use of the individual to whom it
addresses.If the reader of this e-mail is not the intended recipient or authorized agent, the reader is hereby notified
thatany unauthorized viewing, dissemination, distribution or copying of this e-mail is strictly prohibited. If you have
receivedthis e-mail in error, please notify the sender by replying to this message and destroy all occurrences of this
e-mailimmediately. 
Thank you.


Re: Please help me write a query

От
Justin Graf
Дата:
On 5/27/2010 9:45 AM, Nikolas Everett wrote:
Sorry.  Here is the setup:
CREATE TABLE test (id BIGSERIAL PRIMARY KEY, state1 INT NOT NULL, state2 INT NOT NULL, timestamp TIMESTAMP);
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '12 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 2, now() - interval '11 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '10 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (2, 1, now() - interval '9 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '8 hours');


I want to write a query that spits out:
 state1 |         timestamp          
--------+----------------------------
      1 | now() - interval '12 hours'
      2 | now() - interval '9 hours'
      1 | now() - interval '8 hours'


Have a question what makes  these values different other than the timestamp???

1, 1, now() - interval '12 hours'
1, 1, now() - interval '10 hours'

The reason i ask, is because you show 1, 1, now() - interval '8 hours'  in the desired output.   What logic keeps the 8 hour and 12 hour but not the 10hour interval???

Its kinda hard to understand why the 10hour interval is being skipped???

All legitimate Magwerks Corporation quotations are sent in a .PDF file attachment with a unique ID number generated by our proprietary quotation system. Quotations received via any other form of communication will not be honored.

CONFIDENTIALITY NOTICE: This e-mail, including attachments, may contain legally privileged, confidential or other information proprietary to Magwerks Corporation and is intended solely for the use of the individual to whom it addresses. If the reader of this e-mail is not the intended recipient or authorized agent, the reader is hereby notified that any unauthorized viewing, dissemination, distribution or copying of this e-mail is strictly prohibited. If you have received this e-mail in error, please notify the sender by replying to this message and destroy all occurrences of this e-mail immediately.
Thank you.
Вложения

Re: Please help me write a query

От
Nikolas Everett
Дата:
The 10 and 11 hour interval are being skipped because I'm only interested in the transitions of state 1. State 1 only transitioned three times at now - 12, now - 9 and now - 8.

The table has both transitions in it because I frequently care about them both together.  I just don't in this case.

On Thu, May 27, 2010 at 12:36 PM, Justin Graf <justin@magwerks.com> wrote:
On 5/27/2010 9:45 AM, Nikolas Everett wrote:
Sorry.  Here is the setup:
CREATE TABLE test (id BIGSERIAL PRIMARY KEY, state1 INT NOT NULL, state2 INT NOT NULL, timestamp TIMESTAMP);
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '12 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 2, now() - interval '11 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '10 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (2, 1, now() - interval '9 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '8 hours');


I want to write a query that spits out:
 state1 |         timestamp          
--------+----------------------------
      1 | now() - interval '12 hours'
      2 | now() - interval '9 hours'
      1 | now() - interval '8 hours'


Have a question what makes  these values different other than the timestamp???


1, 1, now() - interval '12 hours'
1, 1, now() - interval '10 hours'

The reason i ask, is because you show 1, 1, now() - interval '8 hours'  in the desired output.   What logic keeps the 8 hour and 12 hour but not the 10hour interval???

Its kinda hard to understand why the 10hour interval is being skipped???


All legitimate Magwerks Corporation quotations are sent in a .PDF file attachment with a unique ID number generated by our proprietary quotation system. Quotations received via any other form of communication will not be honored.

CONFIDENTIALITY NOTICE: This e-mail, including attachments, may contain legally privileged, confidential or other information proprietary to Magwerks Corporation and is intended solely for the use of the individual to whom it addresses. If the reader of this e-mail is not the intended recipient or authorized agent, the reader is hereby notified that any unauthorized viewing, dissemination, distribution or copying of this e-mail is strictly prohibited. If you have received this e-mail in error, please notify the sender by replying to this message and destroy all occurrences of this e-mail immediately.
Thank you.

Re: Please help me write a query

От
Nikolas Everett
Дата:
Got it:
    SELECT state1, timestamp 
       FROM (SELECT state1, timestamp, lag(state1) OVER (ORDER BY timestamp) FROM test) as foo 
     WHERE state1 != lag OR lag IS NULL 
ORDER BY timestamp;
 state1 |         timestamp          
--------+----------------------------
      1 | now() - interval '12 hours'
      2 | now() - interval '9 hours'
      1 | now() - interval '8 hours'

Without lag IS NULL I miss the first row.

On Thu, May 27, 2010 at 11:44 AM, Nikolas Everett <nik9000@gmail.com> wrote:
The 10 and 11 hour interval are being skipped because I'm only interested in the transitions of state 1. State 1 only transitioned three times at now - 12, now - 9 and now - 8.

The table has both transitions in it because I frequently care about them both together.  I just don't in this case.


On Thu, May 27, 2010 at 12:36 PM, Justin Graf <justin@magwerks.com> wrote:
On 5/27/2010 9:45 AM, Nikolas Everett wrote:
Sorry.  Here is the setup:
CREATE TABLE test (id BIGSERIAL PRIMARY KEY, state1 INT NOT NULL, state2 INT NOT NULL, timestamp TIMESTAMP);
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '12 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 2, now() - interval '11 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '10 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (2, 1, now() - interval '9 hours');
INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval '8 hours');


I want to write a query that spits out:
 state1 |         timestamp          
--------+----------------------------
      1 | now() - interval '12 hours'
      2 | now() - interval '9 hours'
      1 | now() - interval '8 hours'


Have a question what makes  these values different other than the timestamp???


1, 1, now() - interval '12 hours'
1, 1, now() - interval '10 hours'

The reason i ask, is because you show 1, 1, now() - interval '8 hours'  in the desired output.   What logic keeps the 8 hour and 12 hour but not the 10hour interval???

Its kinda hard to understand why the 10hour interval is being skipped???


All legitimate Magwerks Corporation quotations are sent in a .PDF file attachment with a unique ID number generated by our proprietary quotation system. Quotations received via any other form of communication will not be honored.

CONFIDENTIALITY NOTICE: This e-mail, including attachments, may contain legally privileged, confidential or other information proprietary to Magwerks Corporation and is intended solely for the use of the individual to whom it addresses. If the reader of this e-mail is not the intended recipient or authorized agent, the reader is hereby notified that any unauthorized viewing, dissemination, distribution or copying of this e-mail is strictly prohibited. If you have received this e-mail in error, please notify the sender by replying to this message and destroy all occurrences of this e-mail immediately.
Thank you.


Re: Please help me write a query

От
Tim Landscheidt
Дата:
Nikolas Everett <nik9000@gmail.com> wrote:

> Sorry.  Here is the setup:
> CREATE TABLE test (id BIGSERIAL PRIMARY KEY, state1 INT NOT NULL, state2 INT
> NOT NULL, timestamp TIMESTAMP);
> INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval
> '12 hours');
> INSERT INTO test (state1, state2, timestamp) VALUES (1, 2, now() - interval
> '11 hours');
> INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval
> '10 hours');
> INSERT INTO test (state1, state2, timestamp) VALUES (2, 1, now() - interval
> '9 hours');
> INSERT INTO test (state1, state2, timestamp) VALUES (1, 1, now() - interval
> '8 hours');


> I want to write a query that spits out:
>  state1 |         timestamp
> --------+----------------------------
>       1 | now() - interval '12 hours'
>       2 | now() - interval '9 hours'
>       1 | now() - interval '8 hours'

> Standard grouping destroys the third row so that's out.  No grouping at all
> gives repeats of state1.  Is this what partitioning is for?

Partitioning usually means splitting data across several
tables for faster access which is probably not what you want
here.

  A simple solution would be to use LAG() and discard rows
where the current value is equal to the preceding value:

| SELECT state1, timestamp
|   FROM
|     (SELECT id,
|             state1,
|             state2,
|             LAG(state1) OVER (ORDER BY timestamp) AS prevstate1,
|             timestamp FROM test) AS SubQuery
|   WHERE state1 IS DISTINCT FROM prevstate1
|   ORDER BY timestamp;

Tim