| Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
group_id::=
GROUP_ID distinguishes duplicate groups resulting from a GROUP BY specification. It is therefore useful in filtering out duplicate groupings from the query result. It returns an Oracle NUMBER to uniquely identify duplicate groups. This function is applicable only in a SELECT statement that contains a GROUP BY clause.
If n duplicates exist for a particular grouping, then GROUP_ID returns numbers in the range 0 to n-1.
The following example assigns the value "1" to the duplicate co.country_region grouping from a query on the sample tables sh.countries and sh.sales:
SELECT co.country_region, co.country_subregion, SUM(s.amount_sold) "Revenue", GROUP_ID() g FROM sales s, customers c, countries co WHERE s.cust_id = c.cust_id AND c.country_id = co.country_id AND s.time_id = '1-JAN-00' AND co.country_region IN ('Americas', 'Europe') GROUP BY co.country_region, ROLLUP (co.country_region, co.country_subregion); COUNTRY_REGION COUNTRY_SUBREGION Revenue G -------------------- -------------------- ---------- ---------- Americas Northern America 220844 0 Americas Southern America 10872 0 Europe Eastern Europe 12751 0 Europe Western Europe 558686 0 Americas 231716 0 Europe 571437 0 Americas 231716 1 Europe 571437 1
You could add the following HAVING clause to the end of the statement to ensure that only rows with GROUP_ID < 1 are returned:
HAVING GROUP_ID() < 1