Search Postgresql Archives

Re: updating rows which have a common value forconsecutive dates

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



Hi David,
I had just figured out the sub-query requirement when you replied.  So
now I've got this working:
SELECT * FROM (
SELECT testname,os,arch,build_type,branch,current_status,last_update,rank()
OVER
(PARTITION BY testname,os,arch,branch,build_type ORDER BY last_update
DESC) AS myrank
FROM mytable
WHERE current_status='FAILED' AND age(now(),last_update) <= INTERVAL
'15 days') blah
where myrank=2 ;

However, I'm getting a bit lost at this point as to what I need to do
next.  I've been googling on "WITH CTE" and its mostly going over my
head.  Could you give me more of a hint about this 3rd layer of
sub-query?

thanks


On Wed, Apr 13, 2011 at 10:17 PM, David Johnston <polobo@xxxxxxxxx> wrote:
> You need to turn the query with the window function into a sub-query and then in the outer query you can refer to the inner-query's rank() column. ÂThe inner query should effectively get you the last two test results for each context and then you can check to see if any of those failed.
>
> I have a hunch you might need a third layer of sub-queries to handle the failure aspect of the requirement properly; possibly as part of a "WITH" CTE. ÂYou for sure need to in order to. Properly utilize the rank() function limiting.
>
> Dave
>
> On Apr 14, 2011, at 0:52, Lonni J Friedman <netllama@xxxxxxxxx> wrote:
>
>> Hi David,
>> Thanks for your reply. ÂI'm using 8.4.7, so window functions are
>> certainly an option, although I've admittedly never used them before.
>> I've spent the past few hours reading the dox, and I now have a
>> rudimentary understanding of window functions. ÂI tried to compose a
>> query based on your suggestion, but I think i'm running up against my
>> lack of experience. ÂThis query seems to give me all failures but not
>> neccesarily when there are two in a row for a unique group (although
>> I'm still not 100% certain its actually returning only last_update
>> consecutive rows):
>> SELECT testname,os,arch,build_type,branch,current_status,last_update,rank()
>> OVER (PARTITION BY testname,os,arch,branch,build_type ORDER BY
>> last_update DESC) FROM mytable WHERE current_status='FAILED' AND
>> age(now(),last_update) <= INTERVAL '15 days'
>>
>> However, if I'm understanding how this works, what I really care about
>> is when a rank=2 exists, as that's truly when something failed for two
>> consecutive last_update's. ÂI thought this might do it, but apparently
>> I'm doing it wrong:
>>
>> SELECT testname,os,arch,build_type,branch,current_status,last_update,rank()
>> OVER (PARTITION BY testname,os,arch,branch,build_type ORDER BY
>> last_update DESC) FROM mytable WHERE current_status='FAILED' AND
>> age(now(),last_update) <= INTERVAL '15 days' AND rank()=2 ;
>> ERROR: Âwindow function call requires an OVER clause
>> LINE 1: ... age(now(),last_update) <= INTERVAL '15 days' AND rank()=2 ;
>>
>> How do I restrict the results to only show when rank=2 ?
>>
>> thanks!
>>
>>
>> On Wed, Apr 13, 2011 at 9:57 AM, David Johnston <polobo@xxxxxxxxx> wrote:
>>> If you have the ability to use Window functions you can group (as necessary), order by last_update, and then use rank() to number each test run sequentially. ÂThen you can limit the results to Â( rank() <= 2 AND current_status = 'FAILED' ).
>>>
>>> David J.
>>>
>>> -----Original Message-----
>>> From: pgsql-general-owner@xxxxxxxxxxxxxx [mailto:pgsql-general-owner@xxxxxxxxxxxxxx] On Behalf Of Lonni J Friedman
>>> Sent: Wednesday, April 13, 2011 3:34 AM
>>> To: pgsql-general
>>> Subject:  updating rows which have a common value forconsecutive dates
>>>
>>> Greetings,
>>> I have a table full of automated test data, which continuously has new unique data inserted:
>>>
>>>  ÂColumn   |      ÂType       |
>>> ÂModifiers
>>> ----------------+-----------------------------+-------------------------
>>> ----------------+-----------------------------+-------------------------
>>> ----------------+-----------------------------+-----------
>>> Âid       | integer           | not null default
>>> nextval('dbltests_id_seq'::regclass)
>>> Âtestname    | text            Â| not null
>>> Âlast_update  Â| timestamp without time zone | not null default now()
>>> Âcurrent_status | text            Â| not null
>>> Âos       | text            Â| not null
>>> Âarch      | text            Â| not null
>>> Âbuild_type   | text            Â| not null
>>> Âbranch     | text            Â| not null
>>>
>>> The 'testname' column contains many different tests, and each unique 'testname' has numerous different associated os,arch,build_type & branch values. ÂFor example, testname='foo' will run on os='Linux',arch='i686',build_type='debug',branch='t38', and also on os='Windows7',arch='x86_64',build_type='release',branch='r40', etc, and there will be many other different testname's with similar permutations of the os,arch,build_type & branch columns. ÂSo for example, there will also be testname='bar' or testname='omega' or testname='sigma' for the other assorted os,arch,build_type & branch permutations.
>>>
>>> The current_status column is either 'PASSED' or 'FAILED'.
>>>
>>> What I'm struggling with is how to put together a SQL query which shows me all instances of a given testname permutation
>>> (os,arch,build_type,branch) which has a current_status value of 'FAILED' for two or more most recent consecutive 'last_update' values.
>>>
>>> Suggestions welcome.
>>>
>>> thanks in advance!

-- 
Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general



[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]
  Powered by Linux