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

Coalesce thru a hierarchy?

Coalesce thru a hierarchy?

(OP)
I have a table with a business structure; Branch (required) Warehouse, ProfitCenter and AccountNumber are optional. I will pass in all four values and I want the first record that matches in a specific order:
Branch and AccountNumber
Branch and ProfitCenter
Branch and Warehouse
Branch

So, this rules table may have a record for a specific branch and then an override rule for a specific profitcenter within that branch. Since Branch and ProfitCenter overrides just Branch I want to return the record with Branch and ProfitCenter (there is other data in that row, these are just the criterion I use to identify the row). I have gone around and around with myself how best to accomplish this. I had thought I could do a coalesce in the select statement, something like

CODE

coalesce((select mincasecount from tbl where branch=@branch and account=@account),(select mincasecount from tbl where branch=@branch and profitcenter=@profitcenter),(select mincasecount from tbl where branch = @branch and warehouse=@warehouse),(select mincasecount from tbl where branch = @branch))
from tbl
where branch=@branch and (account=@account OR profitcenter=@profitcenter OR warehouse=@warehouse) 

but this fails in that it can choose more than one record in the where clause. I need something like

CODE

where branch=@branch and coalesce(account=@account,profitcenter=@profitcenter,warehouse=@warehouse) 

but I can't find the correct syntax for what I need.

Any thoughts, suggestions or correction?

thanks,
Willie

RE: Coalesce thru a hierarchy?

this should do it based on the little information supplied

CODE

select mincasecount
from (
select mincasecount
     , row_number() over(order by case
                                  when account = @account then 1
                                  when profitcenter = @profitcenter then 2
                                  when warehouse = @warehouse then 3
                                  else 4
                                  end
                        ) rownum
from tbl
where branch=@branch and (account=@account OR profitcenter=@profitcenter OR warehouse=@warehouse or 1=1) -- 1=1 used so any record that matches @branch but not the others is selected 
) t
where rownum = 1 

Regards

Frederico Fonseca
SysSoft Integrated Ltd
www.syssoft-int.com

FAQ219-2884: How Do I Get Great Answers To my Tek-Tips Questions?
FAQ181-2886: How can I maximize my chances of getting an answer?

RE: Coalesce thru a hierarchy?

(OP)
Nice solution, thank you!

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