Formula to identify status of requisition when there are multiple possible scenerios

u4carson

New Member
Joined
May 21, 2018
Messages
12
I am hoping to find assistance with a formula that will help me identify which requisitions have been fully or partially awarded.

Each requisition may have multiple lines and none, some, or all of the lines might be awarded. In the example below Requisition 111111 has three line items, but only line three has been awarded so the requisition is "partially awarded." Requisition 444444 has three line items and no lines have been awarded so it is "not awarded."

The difficulty I am having is that I need each instance of the requisition to reflect this information. For instance with requisition 111111, line items 1, 2 and 3 must all state the same status (in this case partially awarded) even though only one line has an award number associated with it.

As a note, there can be more than one award number per requisition as shown in example 66666 below.

I am looking for a formula to complete the "Requisition Status" column in the image below.

Thank you.
[TABLE="width: 500"]
<tbody>[TR]
[TD]REQUISTION
[/TD]
[TD]LINE
[/TD]
[TD]AWARD NUMBER
[/TD]
[TD]REQUISITION STATUS
[/TD]
[/TR]
[TR]
[TD]111111
[/TD]
[TD]1
[/TD]
[TD]-
[/TD]
[TD]PARTIAL AWARD
[/TD]
[/TR]
[TR]
[TD]111111
[/TD]
[TD]2
[/TD]
[TD]-
[/TD]
[TD]PARTIAL AWARD
[/TD]
[/TR]
[TR]
[TD]111111
[/TD]
[TD]3
[/TD]
[TD]123111
[/TD]
[TD]PARTIAL AWARD
[/TD]
[/TR]
[TR]
[TD]444444
[/TD]
[TD]1
[/TD]
[TD]-
[/TD]
[TD]NOT AWARDED
[/TD]
[/TR]
[TR]
[TD]444444
[/TD]
[TD]2
[/TD]
[TD]-
[/TD]
[TD]NOT AWARDED
[/TD]
[/TR]
[TR]
[TD]444444
[/TD]
[TD]3
[/TD]
[TD]-
[/TD]
[TD]NOT AWARDED
[/TD]
[/TR]
[TR]
[TD]666666
[/TD]
[TD]1
[/TD]
[TD]223111
[/TD]
[TD]AWARDED
[/TD]
[/TR]
[TR]
[TD]666666
[/TD]
[TD]2
[/TD]
[TD]223111
[/TD]
[TD]AWARDED
[/TD]
[/TR]
[TR]
[TD]666666
[/TD]
[TD]3
[/TD]
[TD]333222
[/TD]
[TD]AWARDED
[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Try this:

=IF(COUNTIF($A$2:$A$10,A2)=COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,">0"),"",
IF(COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,">0"),"PARTIAL ","NOT "))&"AWARDED"


Markmzz
 
Upvote 0
Markmzz,

I failed to mention that the award numbers contain text which cause your formula (which otherwise does exactly what I need) to not work. A sample award number is 123C7818F0087. If I substitute the award number with a number your formula works, otherwise it doesn't recognize the field. I apologize, I should have mentioned this in my original post. Any ideas? Thanks!
 
Upvote 0
Markmzz,
I failed to mention that the award numbers contain text which cause your formula (which otherwise does exactly what I need) to not work. A sample award number is 123C7818F0087. If I substitute the award number with a number your formula works, otherwise it doesn't recognize the field. I apologize, I should have mentioned this in my original post. Any ideas? Thanks!

Try this is this case:

=IF(COUNTIF($A$2:$A$10,A2)=COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,"<>-"),"",
IF(COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,"<>-"),"PARTIAL ","NOT "))&"AWARDED"


Markmzz
 
Upvote 0
Try this is this case:

=IF(COUNTIF($A$2:$A$10,A2)=COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,"<>-"),"",
IF(COUNTIFS($A$2:$A$10,A2,$C$2:$C$10,"<>-"),"PARTIAL ","NOT "))&"AWARDED"


Markmzz

MArkmzz,

This worked! Thank you! I learned something today!!!
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,157
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top