Just using excel formulas, finding out unique RMs in a group id

SRana

New Member
Joined
Dec 5, 2018
Messages
8
Hi guys
I have a database which contains customer ids in A2:A10000. These customer ids are grouped into various group ids which are in B2:B10000. One group id can be tagged to just one customer id or or can be tagged to upto 50 customer ids. These customer ids are further managed by Relationship manager codes in C2:C10000. One relationship manager code can be tagged to just one customer id or can be tagged to many customer ids of same group id or any other group id.

The dataset is sorted first by group id and then by customer id.

Using just excel formulas, I want to do the following

1. In column D, plot 1 if a group Id is unique, else plot NULL.
2. wherever 1 is found in column D, then in column E, plot count of unique relationship manager codes which are tagged to ALL customer ids tagged to that group id.

Pl help. Thanks!
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
what version of excel are you also USING / expecting to work with - please update profile as the solution will depend on version
NOT sure i understand how a groupID can be assigned to 1 or many customer IDs - how the group ID is unique - do you mean ONLY 1 groupID exists for 1 customer ID and so entered int the database once

as already mentioned / requested

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

This will possibly enable a quicker and more accurate solution for you.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC

then put the sample spreadsheet onto a share

I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed

Make sure you set any share or google to share to everyone
 
Upvote 0
Hi guys
I have a database which contains customer ids in A2:A10000. These customer ids are grouped into various group ids which are in B2:B10000. One group id can be tagged to just one customer id or or can be tagged to upto 50 customer ids. These customer ids are further managed by Relationship manager codes in C2:C10000. One relationship manager code can be tagged to just one customer id or can be tagged to many customer ids of same group id or any other group id.

The dataset is sorted first by group id and then by customer id.

Using just excel formulas, I want to do the following

1. In column D, plot 1 if a group Id is unique, else plot NULL.
2. wherever 1 is found in column D, then in column E, plot count of unique relationship manager codes which are tagged to ALL customer ids tagged to that group id.

Pl help. Thanks!
 

Attachments

  • 1000225224.png
    1000225224.png
    206.9 KB · Views: 5
Upvote 0
images are a pain, as i have to type it all out
and also you have not replied to what version of excel

FILTER() and ROWS() and UNIQUE() would probably do what you need - BUT not all versions have those functions

HENCE XL2BB request

Note: Images are difficult to see , and also requires that I input all the data myself, which means I may make an error, which is very time consuming, and from my point of view less likely to get a response, if a complicated spreadsheet. Plus we cannot see any of the formulas used.

Therefore -

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.
 
Upvote 0
for unique group
=IF(COUNTIF($C$2:C2,C2)=1,1,"")

count of manager

=IF(D2=1,ROWS(UNIQUE(FILTER($B$2:$B$100,$C$2:$C$100=C2))),"")

Book1
ABCDE
1custidcodegrroupCountUnique count
2abc0173611
3abc029913
4abc0399  
5abc0499  
6abc0548711
7abc0656511
8abc06565  
9abc0836317
10abc09363  
11abc01363  
12abc11363  
13abc01363  
14abc13363  
15abc14363  
16abc15363  
17abc1677411
18abc16774  
19abc1822212
20abc19222  
Sheet1
Cell Formulas
RangeFormula
D2:D20D2=IF(COUNTIF($C$2:C2,C2)=1,1,"")
E2:E20E2=IF(D2=1,ROWS(UNIQUE(FILTER($B$2:$B$100,$C$2:$C$100=C2))),"")
 
Upvote 0
Solution
Excel version is 365.

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
for unique group
=IF(COUNTIF($C$2:C2,C2)=1,1,"")

count of manager

=IF(D2=1,ROWS(UNIQUE(FILTER($B$2:$B$100,$C$2:$C$100=C2))),"")

Book1
ABCDE
1custidcodegrroupCountUnique count
2abc0173611
3abc029913
4abc0399  
5abc0499  
6abc0548711
7abc0656511
8abc06565  
9abc0836317
10abc09363  
11abc01363  
12abc11363  
13abc01363  
14abc13363  
15abc14363  
16abc15363  
17abc1677411
18abc16774  
19abc1822212
20abc19222  
Sheet1
Cell Formulas
RangeFormula
D2:D20D2=IF(COUNTIF($C$2:C2,C2)=1,1,"")
E2:E20E2=IF(D2=1,ROWS(UNIQUE(FILTER($B$2:$B$100,$C$2:$C$100=C2))),"")
This is the solution I was looking for!
Thanks very much for your support!
 
Upvote 0
you are welcome
would be useful to update your profile with the version of excel - for any future questions you may ask here
 
Upvote 0

Forum statistics

Threads
1,223,993
Messages
6,175,844
Members
452,675
Latest member
duongtruc1610

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