Discussions
Categories
- 197K All Categories
- 2.5K Data
- 546 Big Data Appliance
- 1.9K Data Science
- 450.8K Databases
- 221.9K General Database Discussions
- 3.8K Java and JavaScript in the Database
- 31 Multilingual Engine
- 552 MySQL Community Space
- 479 NoSQL Database
- 7.9K Oracle Database Express Edition (XE)
- 3.1K ORDS, SODA & JSON in the Database
- 556 SQLcl
- 4K SQL Developer Data Modeler
- 187.2K SQL & PL/SQL
- 21.4K SQL Developer
- 296.4K Development
- 17 Developer Projects
- 139 Programming Languages
- 293.1K Development Tools
- 110 DevOps
- 3.1K QA/Testing
- 646.1K Java
- 28 Java Learning Subscription
- 37K Database Connectivity
- 161 Java Community Process
- 105 Java 25
- 22.1K Java APIs
- 138.2K Java Development Tools
- 165.3K Java EE (Java Enterprise Edition)
- 19 Java Essentials
- 162 Java 8 Questions
- 86K Java Programming
- 81 Java Puzzle Ball
- 65.1K New To Java
- 1.7K Training / Learning / Certification
- 13.8K Java HotSpot Virtual Machine
- 94.3K Java SE
- 13.8K Java Security
- 205 Java User Groups
- 24 JavaScript - Nashorn
- Programs
- 474 LiveLabs
- 39 Workshops
- 10.2K Software
- 6.7K Berkeley DB Family
- 3.5K JHeadstart
- 5.7K Other Languages
- 2.3K Chinese
- 175 Deutsche Oracle Community
- 1.1K Español
- 1.9K Japanese
- 233 Portuguese
SQL Help, Pick highest Spend

Kodiak_Seattle
Member Posts: 565
Oralce 10G.
I have a Table with many unique records, kinda looks like this:
customer_key | BB | CL | LA
123 100 300 50
456 65 125 658
789 12 5 98
I need to take the highest spend.
customer_key | SPEND
123 300
456 658
789 98
Not sure how do this since, the field have different names ?
I have a Table with many unique records, kinda looks like this:
customer_key | BB | CL | LA
123 100 300 50
456 65 125 658
789 12 5 98
I need to take the highest spend.
customer_key | SPEND
123 300
456 658
789 98
Not sure how do this since, the field have different names ?
Best Answer
-
Hi,
Use a CASE expression.
Assuming the numbers are distinct and not NULL:SELECT customer_key , GREATEST ( bb , cl , la ) AS spend , CASE WHEN bb >= GREATEST (cl, la) THEN 'BB' WHEN cl >= la THEN 'CL' ELSE 'LA' END AS column_name FROM table_x ;
Answers
-
Hi,
Assuming the columns bb, cl and la are never NULL:SELECT customer_key , GREATEST ( bb , cl , la ) AS spend FROM TABLE_X ;
Assuming the numbers can be NULL, is there a lower bound to their possible values (such as 0)?
If so, use NVL to map NULLs to an impossibly low value, e.g. NVL (bb, -1). You may want to use NULLIF to map that back to NULL in the event that all 3 columns are NULL.
If not, unpivot the 3 columns in to one column and use the aggregate MAX function. -
Cooool, let me try that out, thanks!
-
Ok, this worked, I guess I need one more thing, I need an additional field that will tell me which column the Greatest Spend Came from, like BB, or CL, or LA ?
How would something like that be done ? -
Hi,
Use a CASE expression.
Assuming the numbers are distinct and not NULL:SELECT customer_key , GREATEST ( bb , cl , la ) AS spend , CASE WHEN bb >= GREATEST (cl, la) THEN 'BB' WHEN cl >= la THEN 'CL' ELSE 'LA' END AS column_name FROM table_x ;
-
Thank you for your time!
-
I like simple case expression
SELECT customer_key,GREATEST(bb,cl,la) AS spend CASE GREATEST(bb,cl,la) when bb then 'BB' when cl then 'CL' when la then 'LA' END AS column_name FROM table_x;
This discussion has been closed.