Thread: Return 30% of results?
Is there a way to return a percentage of the rows found? I tried window functions but get an error... ERROR: syntax error at or near "OVER" SELECT id, cume_dist FROM ( SELECT id, cume_dist() OVER (ORDER BY id) FROM employees ) s WHERE cume_dist < 0.3
Nick wrote on 18.09.2009 23:31: > Is there a way to return a percentage of the rows found? I tried > window functions but get an error... > > ERROR: syntax error at or near "OVER" > > SELECT id, cume_dist FROM ( > SELECT id, cume_dist() OVER (ORDER BY id) FROM employees > ) s > WHERE cume_dist < 0.3 > Works for me. Are you sure you are using Postgrs 8.4? (Windowing functions are not available in earlier versions) Regards Thomas
//Display the top 40 % of rows in BB_DEPARTMENTHTH
SQL> select ROWNUM,ID FROM EMPLOYEES WHERE ROWNUM < .3*(SELECT COUNT(ID) FROM BB
_DEPARTMENT) GROUP BY ROWNUM,ID;
ROWNUM
----------
1
Martin Gainty
______________________________________________
Verzicht und Vertraulichkeitanmerkung/Note de déni et de confidentialité
Diese Nachricht ist vertraulich. Sollten Sie nicht der vorgesehene Empfaenger sein, so bitten wir hoeflich um eine Mitteilung. Jede unbefugte Weiterleitung oder Fertigung einer Kopie ist unzulaessig. Diese Nachricht dient lediglich dem Austausch von Informationen und entfaltet keine rechtliche Bindungswirkung. Aufgrund der leichten Manipulierbarkeit von E-Mails koennen wir keine Haftung fuer den Inhalt uebernehmen.
Ce message est confidentiel et peut être privilégié. Si vous n'êtes pas le destinataire prévu, nous te demandons avec bonté que pour satisfaire informez l'expéditeur. N'importe quelle diffusion non autorisée ou la copie de ceci est interdite. Ce message sert à l'information seulement et n'aura pas n'importe quel effet légalement obligatoire. Étant donné que les email peuvent facilement être sujets à la manipulation, nous ne pouvons accepter aucune responsabilité pour le contenu fourni.
> From: nboutelier@gmail.com
> Subject: [GENERAL] Return 30% of results?
> Date: Fri, 18 Sep 2009 14:31:29 -0700
> To: pgsql-general@postgresql.org
>
> Is there a way to return a percentage of the rows found? I tried
> window functions but get an error...
>
> ERROR: syntax error at or near "OVER"
>
> SELECT id, cume_dist FROM (
> SELECT id, cume_dist() OVER (ORDER BY id) FROM employees
> ) s
> WHERE cume_dist < 0.3
>
> --
> Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-general
Hotmail: Powerful Free email with security by Microsoft. Get it now.
On Fri, Sep 18, 2009 at 07:54:30PM -0400, Martin Gainty wrote: > > //Display the top 40 % of rows in BB_DEPARTMENT > > SQL> select ROWNUM,ID FROM EMPLOYEES WHERE ROWNUM < .3*(SELECT COUNT(ID) FROM BB > _DEPARTMENT) GROUP BY ROWNUM,ID; > > ROWNUM > ---------- > 1 > HTH > Martin Gainty That's Oracle, not PostgreSQL. Are you really trying to help here? Cheers, David. -- David Fetter <david@fetter.org> http://fetter.org/ Phone: +1 415 235 3778 AIM: dfetter666 Yahoo!: dfetter Skype: davidfetter XMPP: david.fetter@gmail.com Remember to vote! Consider donating to Postgres: http://www.postgresql.org/about/donate
On Sep 18, 3:40 pm, spam_ea...@gmx.net (Thomas Kellerer) wrote: > Nick wrote on 18.09.2009 23:31:> Is there a way to return a percentage of the rows found? I tried > > window functions but get an error... > > > ERROR: syntax error at or near "OVER" > > > SELECT id, cume_dist FROM ( > > SELECT id, cume_dist() OVER (ORDER BY id) FROM employees > > ) s > > WHERE cume_dist < 0.3 > > Works for me. Are you sure you are using Postgrs 8.4? > (Windowing functions are not available in earlier versions) > > Regards > Thomas > > -- > Sent via pgsql-general mailing list (pgsql-gene...@postgresql.org) > To make changes to your subscription:http://www.postgresql.org/mailpref/pgsql-general Yeah, im actually not using 8.4. Any other alternatives?
On Sat, Sep 19, 2009 at 12:27:10AM -0700, nick wrote: > On Sep 18, 3:40 pm, spam_ea...@gmx.net (Thomas Kellerer) wrote: > > Nick wrote on 18.09.2009 23:31:> Is there a way to return a percentage of the rows found? I tried > > > window functions but get an error... > > > > > ERROR: syntax error at or near "OVER" > > > > > SELECT id, cume_dist FROM ( > > > SELECT id, cume_dist() OVER (ORDER BY id) FROM employees > > > ) s > > > WHERE cume_dist < 0.3 > > > > Works for me. Are you sure you are using Postgrs 8.4? > > (Windowing functions are not available in earlier versions) > > > > Regards > > Thomas > > > > -- > > Sent via pgsql-general mailing list (pgsql-gene...@postgresql.org) > > To make changes to your subscription:http://www.postgresql.org/mailpref/pgsql-general > > Yeah, im actually not using 8.4. Any other alternatives? The easiest way would be to upgrade to 8.4 because the workarounds for previous versions are complicated and bug-prone. Cheers, David. -- David Fetter <david@fetter.org> http://fetter.org/ Phone: +1 415 235 3778 AIM: dfetter666 Yahoo!: dfetter Skype: davidfetter XMPP: david.fetter@gmail.com Remember to vote! Consider donating to Postgres: http://www.postgresql.org/about/donate
On Sat, Sep 19, 2009 at 3:27 AM, nick <nboutelier@gmail.com> wrote: > On Sep 18, 3:40 pm, spam_ea...@gmx.net (Thomas Kellerer) wrote: >> Nick wrote on 18.09.2009 23:31:> Is there a way to return a percentage of the rows found? I tried >> > window functions but get an error... >> >> > ERROR: syntax error at or near "OVER" >> >> > SELECT id, cume_dist FROM ( >> > SELECT id, cume_dist() OVER (ORDER BY id) FROM employees >> > ) s >> > WHERE cume_dist < 0.3 >> >> Works for me. Are you sure you are using Postgrs 8.4? >> (Windowing functions are not available in earlier versions) Using 8.3? You can use arrays to stack a set and then pull some records out: create or replace function some_employees() returns setof employee as $$ declare employees_arr employees[]; n_found int; n_returned int; begin select array ( select employees from employees where x order by y ) into employees_arr; n_found := array_upper(employees_arr, 1); n_returned := n_found * 0.3; return query select (e).* from unnest(employees_arr[1:n_returned]) as e; end; $$ language plpgsql; couple notes: *) 8.3 has doesn't have unnest, but it can be made (google array_explode). *) probably some typos in above...i didn't test it *) needs some error checking *) not scalable to huge numbers of records *) 8.4 can do this much easier! merlin