From: | Thomas Kellerer <spam_eater(at)gmx(dot)net> |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: Correlated Subquery and calculated column non-functional |
Date: | 2009-10-30 17:47:08 |
Message-ID: | hcf8qr$i2h$1@ger.gmane.org |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
The Frog wrote on 30.10.2009 11:07:
> select
> product.manufacturer,
> product.brand,
> SUM(sales.qtysold * sales.unitprice) as turnover,
> (select count(*) from cube_sales.sales as Q WHERE SUM(sales.qtysold *
> sales.unitprice) > turnover) + 1 as rank
> from
> cube_sales.sales INNER JOIN
> cube_sales.product ON
> sales.productid = product.productid
> group by
> product.manufacturer,
> product.brand;
>
> I am receiving a : column "turnover" does not exist
> SQL state: 42703
> Character: 155
>
> I understand that there is some difference with subselects in Postgres
> vs MySQL or Oracle for example, but I am out of my depth on this one.
>
> Can anyone help?
You can't use a column alias as reference for other expressions inside the same statement (I don't think that is different in Oracle or MySQL)
Btw: your statement will be horribly in-efficient as the select count(*) will be execute for *every* row from the main query.
If I understand your statement correctly, you can get rid of the "sub-select" completely with Postgres 8.4
SELECT product.manufacturer,
product.brand,
SUM(sales.qtysold * sales.unitprice) as turnover,
rank() over (partition by manufacturer, brand order by SUM(sales.qtysold * sales.unitprice)) as rank
FROM cube_sales.sales
INNER JOIN cube_sales.product ON sales.productid = product.productid
GROUP BY product.manufacturer,
product.brand;
(Not tested)
Thomas
From | Date | Subject | |
---|---|---|---|
Next Message | Blake Starkenburg | 2009-10-30 17:47:26 | Possible to UPDATE array[] columns? |
Previous Message | Richard Broersma | 2009-10-30 17:46:35 | Re: Correlated Subquery and calculated column non-functional |