INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

Should be simple SQL problem

Should be simple SQL problem

(OP)
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?

RE: Should be simple SQL problem

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  

RE: Should be simple SQL problem

(OP)
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

RE: Should be simple SQL problem

Instead of converting numbers to strings and vice versa,
you can do the same trick with numbers using arithmetics:

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) as min_num,
  max(num) as max_num,
  sum(num) as sum_num,
  mod(min(10*num + mo), 10) as min_mo,
  mod(max(10*num + mo), 10) as max_mo
from 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

RE: Should be simple SQL problem

(OP)
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

RE: Should be simple SQL problem

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.

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close