Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations SkipVought on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Should be simple SQL problem 1

Status
Not open for further replies.

mpatter5

Technical User
Nov 27, 2007
8
0
0
US
I have what seems like a simple problem, but I can't seem to figure it out.

As an example, I have the following db2 table:
Table = TESTB
MO NUM
1 8
2 40
3 16
4 25
5 36
6 2

I need to find the following values in a single query:
min(num) = 2
max(num) = 40
sum(num) = 127
mo of the min(num) = 6
mo of the max(num) 2

This gets all but the last two:
select min(num),
max(num)
sum(num)
from testb

How do I get the mo related to the min(num) as well as the mo related to the max(num) incorporated into the same statement?
 
Code:
select 
  min(num) as min,
  max(num) as max,
  sum(num) as sum,
  (select mo from testb 
   where num in (select min(num) from testb)) as mo_min,
  (select mo from testb 
   where num in (select max(num) from testb)) as mo_max
from testb
delivers this result
Code:
MIN   MAX   SUM   MO_MIN  MO_MAX
  2    40   127      6       2
 
Thanks for your response. It worked perfectly. Unfortunately, I am querying some very large tables and performance is a huge issue. Since I only want to read the table once, the following works more efficiently:

Code:
with TESTB (MO, NUM) as
(select 1,  8
from sysibm.sysdummy1 union all
select 2, 40
from sysibm.sysdummy1 union all
select 3, 16
from sysibm.sysdummy1 union all
select 4, 25
from sysibm.sysdummy1 union all
select 5, 36
from sysibm.sysdummy1 union all
select 6,  2
from sysibm.sysdummy1 ) 
select 
min(num) min_num, 
max(num) max_num,
sum(num) sum_num,
INT(SUBSTR(min( digits(num) CONCAT CHAR(mo)),11)) min_mo, 
INT(SUBSTR(max( digits(num) CONCAT CHAR(mo)),11)) max_mo 
from TESTB
 
Instead of converting numbers to strings and vice versa,
you can do the same trick with numbers using arithmetics:
Code:
[COLOR=#6a5acd]with[/color] TESTB (MO, NUM) [COLOR=#6a5acd]as[/color] ( 
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]1[/color],  [COLOR=#ff00ff]8[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1 [COLOR=#804040][b]union[/b][/color] [COLOR=#804040][b]all[/b][/color]
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]2[/color], [COLOR=#ff00ff]40[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1 [COLOR=#804040][b]union[/b][/color] [COLOR=#804040][b]all[/b][/color]
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]3[/color], [COLOR=#ff00ff]16[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1 [COLOR=#804040][b]union[/b][/color] [COLOR=#804040][b]all[/b][/color]
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]4[/color], [COLOR=#ff00ff]25[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1 [COLOR=#804040][b]union[/b][/color] [COLOR=#804040][b]all[/b][/color]
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]5[/color], [COLOR=#ff00ff]36[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1 [COLOR=#804040][b]union[/b][/color] [COLOR=#804040][b]all[/b][/color]
  [COLOR=#804040][b]select[/b][/color] [COLOR=#ff00ff]6[/color],  [COLOR=#ff00ff]2[/color]
  [COLOR=#6a5acd]from[/color] sysibm.sysdummy1) 
[COLOR=#804040][b]select[/b][/color] 
  min(num) [COLOR=#6a5acd]as[/color] min_num, 
  max(num) [COLOR=#6a5acd]as[/color] max_num,
  sum(num) [COLOR=#6a5acd]as[/color] sum_num,
  mod(min([COLOR=#ff00ff]10[/color]*num + mo), [COLOR=#ff00ff]10[/color]) [COLOR=#6a5acd]as[/color] min_mo, 
  mod(max([COLOR=#ff00ff]10[/color]*num + mo), [COLOR=#ff00ff]10[/color]) [COLOR=#6a5acd]as[/color] max_mo
[COLOR=#6a5acd]from[/color] TESTB
result:
Code:
....+....1....+....2....+....3....+....4....+....5....+....6....+....7....+...
      MIN_NUM         MAX_NUM         SUM_NUM          MIN_MO          MAX_MO 
            2              40             127               6               2
 
WOW!!! That works too...
Since the mo field is char datatype in my "Production" db, I tried the following and it seemed to work OK... The (mo) field will always be 6 characters long, but what would you need to do if the field were variable in length? Just make sure that the constant in the MOD() function has more digits than the longest length item contained in the variable length field?
Code:
with testb (acct, mo, num) as
(select 'acct1', '201001',  8
from sysibm.sysdummy1 union all
select 'acct2', '201002', 40
from sysibm.sysdummy1 union all
select 'acct1', '201003', 16
from sysibm.sysdummy1 union all
select 'acct2', '201004', 25
from sysibm.sysdummy1 union all
select 'acct1', '201005', 36
from sysibm.sysdummy1 union all
select 'acct2', '201006',  2
from sysibm.sysdummy1 )
select
     acct as "acct",         
     min(num) as "min(num)", 
     max(num) as "max(num)",
     sum(num) as "sum(num)",
     mod(min(1000000*num + int(mo)), 1000000) as "mo_of_min(num)", 
     mod(max(1000000*num + int(mo)), 1000000) as "mo_of_max(num)"
from testb
group by acct
 
I thought that MO and NUM are numbers, therefore I suggested to use rather arithmetics with MOD function.

But now, when MO is character data I'm not sure if it's more efficient or not than converting into character data:
Code:
with testb (acct, mo, num) as   
(select 'acct1', '201001',  8   
from sysibm.sysdummy1 union all 
select 'acct2', '201002', 40    
from sysibm.sysdummy1 union all 
select 'acct1', '201003', 16    
from sysibm.sysdummy1 union all 
select 'acct2', '201004', 25    
from sysibm.sysdummy1 union all 
select 'acct1', '201005', 36    
from sysibm.sysdummy1 union all 
select 'acct2', '201006',  2    
from sysibm.sysdummy1 )         
select                          
  min(num) as "min(num)",       
  max(num) as "max(num)",       
  sum(num) as "sum(num)",       
  int(substr(min(digits(num) CONCAT mo),11,6)) as min_mo,
  int(substr(max(digits(num) CONCAT mo),11,6)) as max_mo 
from testb
You mean that the field MO should be of variable length? Something like '201' or '9999999999'?
If so then the the aritmetic formula using a constant coefficient (e.g. 1000000) would not work.
Instead, we need to compute the coefficient e.g. like 10*max(length(mo))
But when I tried the following in the select statement
Code:
  ...
  mod(min(10*max(length(mo))*num+int(mo)), 10*max(length(mo))) 
    as "mo_of_min(num)", 
  mod(max(10*max(length(mo))*num+int(mo)), 10*max(length(mo))) 
    as "mo_of_max(num)"
  ...
then I got this error
Argument of function *N contains another function.
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top