|
| 1 | += GROUP BY column alias or position |
| 2 | +:database-version: 23.2.0 |
| 3 | +:database-category: sql |
| 4 | + |
| 5 | +[[feature_summary]] |
| 6 | + |
| 7 | +The GROUP BY column alias feature is a shorthand for not having to repeat lengthy expressions from the `SELECT` clause in the `GROUP BY` and/or `HAVING` clause but instead use the defined column alias. |
| 8 | + |
| 9 | +The GROUP BY position feature is a similar shorthand and great for ad-hoc queries by simply referring to the expression position in the `SELECT` clause. Caution is required when using this feature, however, as it can lead novices to wrong conclusions and unexpected results as they may be surprised by or not aware of that data is being grouped differently when the position of the expression in the `SELECT` clause changes. This is particularly important for `GROUP BY ROLLUP()` and other super-aggregate grouping functions, hence this functionality is guarded behind a session parameter `group_by_position_enabled`. |
| 10 | + |
| 11 | +== GROUP BY column alias |
| 12 | + |
| 13 | +_Note the `GROUP BY combined_name` which refers to a column alias in the `SELECT`._ |
| 14 | +[source,sql] |
| 15 | +[subs="verbatim"] |
| 16 | +---- |
| 17 | +SELECT CONCAT(r.name, ': ', co.name) AS combined_name, |
| 18 | + SUM(co.population/1000/1000) AS population_m |
| 19 | + FROM regions r, countries co |
| 20 | + WHERE r.region_id = co.region_id |
| 21 | + AND r.name IN ('Oceania', 'South America') |
| 22 | + GROUP BY combined_name |
| 23 | + ORDER BY combined_name; |
| 24 | +---- |
| 25 | + |
| 26 | +.Result |
| 27 | +[source,sql] |
| 28 | +[subs="verbatim"] |
| 29 | +---- |
| 30 | +SQL> SELECT CONCAT(r.name, ': ', co.name) AS combined_name, |
| 31 | + SUM(co.population/1000/1000) AS population_m |
| 32 | + FROM regions r, countries co |
| 33 | + WHERE r.region_id = co.region_id |
| 34 | + AND r.name IN ('Oceania', 'South America') |
| 35 | + GROUP BY combined_name |
| 36 | + ORDER BY combined_name; |
| 37 | +
|
| 38 | +COMBINED_NAME POPULATION_M |
| 39 | +------------------------------ ------------ |
| 40 | +Oceania: Australia 23.47 |
| 41 | +Oceania: Fiji .926 |
| 42 | +Oceania: Kiribati .109 |
| 43 | +Oceania: Marshall Islands .076 |
| 44 | +Oceania: Micronesia .104 |
| 45 | +Oceania: Nauru .01 |
| 46 | +Oceania: New Zealand 4.546 |
| 47 | +Oceania: Palau .022 |
| 48 | +Oceania: Papua New Guinea 7.027 |
| 49 | +Oceania: Samoa .201 |
| 50 | +Oceania: Solomon Islands .66 |
| 51 | +Oceania: Tonga .106 |
| 52 | +Oceania: Tuvalu .011 |
| 53 | +Oceania: Vanuatu .288 |
| 54 | +South America: Argentina 44.694 |
| 55 | +South America: Bolivia 11.306 |
| 56 | +South America: Brazil 208.847 |
| 57 | +South America: Chile 17.925 |
| 58 | +South America: Colombia 48.169 |
| 59 | +South America: Ecuador 16.291 |
| 60 | +South America: Guyana .741 |
| 61 | +South America: Paraguay 7.026 |
| 62 | +South America: Peru 31.331 |
| 63 | +South America: Suriname .598 |
| 64 | +South America: Uruguay 3.369 |
| 65 | +South America: Venezuela 31.689 |
| 66 | +
|
| 67 | +26 rows selected. |
| 68 | +---- |
| 69 | + |
| 70 | +== GROUP BY column position |
| 71 | + |
| 72 | +_Note the `GROUP BY ROLLUP (1, 2)` which refers to the first and second column in the `SELECT`._ |
| 73 | +[source,sql] |
| 74 | +[subs="verbatim"] |
| 75 | +---- |
| 76 | +-- Enable the GROUP_BY_POSITION parameter for the session |
| 77 | +ALTER SESSION SET GROUP_BY_POSITION_ENABLED=TRUE; |
| 78 | +
|
| 79 | +SELECT r.name AS region_name, co.name AS country_name, |
| 80 | + SUM(co.population/1000/1000) AS population_m |
| 81 | + FROM regions r, countries co |
| 82 | + WHERE r.region_id = co.region_id |
| 83 | + AND r.name IN ('Oceania', 'South America') |
| 84 | + GROUP BY ROLLUP (1, 2) |
| 85 | + ORDER BY region_name; |
| 86 | +---- |
| 87 | + |
| 88 | +.Result |
| 89 | +[source,sql] |
| 90 | +[subs="verbatim"] |
| 91 | +---- |
| 92 | +SQL> -- Enable the GROUP_BY_POSITION parameter for the session |
| 93 | +SQL> ALTER SESSION SET GROUP_BY_POSITION_ENABLED=TRUE; |
| 94 | +
|
| 95 | +Session altered. |
| 96 | +
|
| 97 | +SQL> SELECT r.name AS region_name, co.name AS country_name, |
| 98 | + SUM(co.population/1000/1000) AS population_m |
| 99 | + FROM regions r, countries co |
| 100 | + WHERE r.region_id = co.region_id |
| 101 | + AND r.name IN ('Oceania', 'South America') |
| 102 | + GROUP BY ROLLUP (1, 2) |
| 103 | + ORDER BY region_name; |
| 104 | +
|
| 105 | +REGION_NAME COUNTRY_NAME POPULATION_M |
| 106 | +------------- ---------------- ------------ |
| 107 | +Oceania Australia 23.47 |
| 108 | +Oceania Fiji .926 |
| 109 | +Oceania Kiribati .109 |
| 110 | +Oceania Marshall Islands .076 |
| 111 | +Oceania Micronesia .104 |
| 112 | +Oceania Nauru .01 |
| 113 | +Oceania New Zealand 4.546 |
| 114 | +Oceania Palau .022 |
| 115 | +Oceania Papua New Guinea 7.027 |
| 116 | +Oceania Samoa .201 |
| 117 | +Oceania Solomon Islands .66 |
| 118 | +Oceania Tonga .106 |
| 119 | +Oceania Tuvalu .011 |
| 120 | +Oceania Vanuatu .288 |
| 121 | +Oceania 37.556 |
| 122 | +South America Argentina 44.694 |
| 123 | +South America Bolivia 11.306 |
| 124 | +South America Brazil 208.847 |
| 125 | +South America Chile 17.925 |
| 126 | +South America Colombia 48.169 |
| 127 | +South America Ecuador 16.291 |
| 128 | +South America Guyana .741 |
| 129 | +South America Paraguay 7.026 |
| 130 | +South America Peru 31.331 |
| 131 | +South America Suriname .598 |
| 132 | +South America Uruguay 3.369 |
| 133 | +South America Venezuela 31.689 |
| 134 | +South America 421.986 |
| 135 | + 459.542 |
| 136 | +
|
| 137 | +29 rows selected. |
| 138 | +---- |
| 139 | + |
| 140 | +=== Caution |
| 141 | + |
| 142 | +Let's assume that the report was supposed to list countries first and the region next to it instead of the current region first and the country next to it. If you change the columns in the `SELECT` but forget to amend the `GROUP BY ROLLUP` clause as well, because you are grouping by column _**position**_ in the `SELECT` list, your results will be grouped differently and be no longer be the same. |
| 143 | + |
| 144 | +[source,sql] |
| 145 | +[subs="verbatim"] |
| 146 | +---- |
| 147 | +-- Enable the GROUP_BY_POSITION parameter for the session (only needed once per session) |
| 148 | +ALTER SESSION SET GROUP_BY_POSITION_ENABLED=TRUE; |
| 149 | +
|
| 150 | +SELECT co.name AS country_name, r.name AS region_name, |
| 151 | + SUM(co.population/1000/1000) AS population_m |
| 152 | + FROM regions r, countries co |
| 153 | + WHERE r.region_id = co.region_id |
| 154 | + AND r.name IN ('Oceania', 'South America') |
| 155 | + GROUP BY ROLLUP (1, 2) |
| 156 | + ORDER BY region_name; |
| 157 | +---- |
| 158 | + |
| 159 | +.Result |
| 160 | +[source,sql] |
| 161 | +[subs="verbatim"] |
| 162 | +---- |
| 163 | +SQL> -- Enable the GROUP_BY_POSITION parameter for the session (only needed once per session) |
| 164 | +SQL> ALTER SESSION SET GROUP_BY_POSITION_ENABLED=TRUE; |
| 165 | +
|
| 166 | +Session altered. |
| 167 | +
|
| 168 | +SQL> SELECT co.name AS country_name, r.name AS region_name, |
| 169 | + SUM(co.population/1000/1000) AS population_m |
| 170 | + FROM regions r, countries co |
| 171 | + WHERE r.region_id = co.region_id |
| 172 | + AND r.name IN ('Oceania', 'South America') |
| 173 | + GROUP BY ROLLUP (1, 2) |
| 174 | + ORDER BY region_name; |
| 175 | +
|
| 176 | +COUNTRY_NAME REGION_NAME POPULATION_M |
| 177 | +---------------- ------------- ------------ |
| 178 | +Samoa Oceania .201 |
| 179 | +Fiji Oceania .926 |
| 180 | +Micronesia Oceania .104 |
| 181 | +Kiribati Oceania .109 |
| 182 | +Marshall Islands Oceania .076 |
| 183 | +Nauru Oceania .01 |
| 184 | +New Zealand Oceania 4.546 |
| 185 | +Papua New Guinea Oceania 7.027 |
| 186 | +Palau Oceania .022 |
| 187 | +Solomon Islands Oceania .66 |
| 188 | +Tonga Oceania .106 |
| 189 | +Tuvalu Oceania .011 |
| 190 | +Australia Oceania 23.47 |
| 191 | +Vanuatu Oceania .288 |
| 192 | +Argentina South America 44.694 |
| 193 | +Bolivia South America 11.306 |
| 194 | +Brazil South America 208.847 |
| 195 | +Chile South America 17.925 |
| 196 | +Colombia South America 48.169 |
| 197 | +Venezuela South America 31.689 |
| 198 | +Guyana South America .741 |
| 199 | +Peru South America 31.331 |
| 200 | +Paraguay South America 7.026 |
| 201 | +Suriname South America .598 |
| 202 | +Uruguay South America 3.369 |
| 203 | +Ecuador South America 16.291 |
| 204 | +Venezuela 31.689 |
| 205 | +Uruguay 3.369 |
| 206 | +Suriname .598 |
| 207 | +Paraguay 7.026 |
| 208 | +Peru 31.331 |
| 209 | +Guyana .741 |
| 210 | +Ecuador 16.291 |
| 211 | +Colombia 48.169 |
| 212 | +Chile 17.925 |
| 213 | +Brazil 208.847 |
| 214 | +Bolivia 11.306 |
| 215 | +Argentina 44.694 |
| 216 | +Samoa .201 |
| 217 | +Vanuatu .288 |
| 218 | +Tuvalu .011 |
| 219 | +Tonga .106 |
| 220 | +Solomon Islands .66 |
| 221 | +Palau .022 |
| 222 | +Papua New Guinea 7.027 |
| 223 | +New Zealand 4.546 |
| 224 | +Nauru .01 |
| 225 | +Marshall Islands .076 |
| 226 | +Kiribati .109 |
| 227 | +Micronesia .104 |
| 228 | +Fiji .926 |
| 229 | + 459.542 |
| 230 | +Australia 23.47 |
| 231 | +
|
| 232 | +53 rows selected. |
| 233 | +---- |
| 234 | + |
| 235 | +In comparison, this does not happen when using the column alias: |
| 236 | + |
| 237 | +[source,sql] |
| 238 | +[subs="verbatim"] |
| 239 | +---- |
| 240 | +SELECT co.name AS country_name, r.name AS region_name, |
| 241 | + SUM(co.population/1000/1000) AS population_m |
| 242 | + FROM regions r, countries co |
| 243 | + WHERE r.region_id = co.region_id |
| 244 | + AND r.name IN ('Oceania', 'South America') |
| 245 | + GROUP BY ROLLUP (region_name, country_name) |
| 246 | + ORDER BY region_name; |
| 247 | +---- |
| 248 | + |
| 249 | +.Result |
| 250 | +[source,sql] |
| 251 | +[subs="verbatim"] |
| 252 | +---- |
| 253 | +SQL> SELECT co.name AS country_name, r.name AS region_name, |
| 254 | + SUM(co.population/1000/1000) AS population_m |
| 255 | + FROM regions r, countries co |
| 256 | + WHERE r.region_id = co.region_id |
| 257 | + AND r.name IN ('Oceania', 'South America') |
| 258 | + GROUP BY ROLLUP (region_name, country_name) |
| 259 | + ORDER BY region_name; |
| 260 | +
|
| 261 | +COUNTRY_NAME REGION_NAME POPULATION_M |
| 262 | +---------------- ------------- ------------ |
| 263 | +Australia Oceania 23.47 |
| 264 | +Fiji Oceania .926 |
| 265 | +Kiribati Oceania .109 |
| 266 | +Marshall Islands Oceania .076 |
| 267 | +Micronesia Oceania .104 |
| 268 | +Nauru Oceania .01 |
| 269 | +New Zealand Oceania 4.546 |
| 270 | +Palau Oceania .022 |
| 271 | +Papua New Guinea Oceania 7.027 |
| 272 | +Samoa Oceania .201 |
| 273 | +Solomon Islands Oceania .66 |
| 274 | +Tonga Oceania .106 |
| 275 | +Tuvalu Oceania .011 |
| 276 | +Vanuatu Oceania .288 |
| 277 | + Oceania 37.556 |
| 278 | +Argentina South America 44.694 |
| 279 | +Bolivia South America 11.306 |
| 280 | +Brazil South America 208.847 |
| 281 | +Chile South America 17.925 |
| 282 | +Colombia South America 48.169 |
| 283 | +Ecuador South America 16.291 |
| 284 | +Guyana South America .741 |
| 285 | +Paraguay South America 7.026 |
| 286 | +Peru South America 31.331 |
| 287 | +Suriname South America .598 |
| 288 | +Uruguay South America 3.369 |
| 289 | +Venezuela South America 31.689 |
| 290 | + South America 421.986 |
| 291 | + 459.542 |
| 292 | +
|
| 293 | +29 rows selected. |
| 294 | +---- |
| 295 | + |
| 296 | +== Benefits |
| 297 | + |
| 298 | +GROUP BY column alias and position are both convenient shorthands for writing concise ad-hoc SQL statements. |
| 299 | +Extra caution should be given when using GROUP BY column position as changing the column position in the `SELECT` part can have direct influence over the grouping of the data. |
| 300 | + |
| 301 | +== Further information |
| 302 | + |
| 303 | +* Availability: All Offerings |
| 304 | +* link:https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/SELECT.html#GUID-CFA006CA-6FF1-4972-821E-6996142A51C6__I2065777[Documentation] |
0 commit comments