Forum Discussion
Any to any comparison in excel
hi Everyone
Book1.xls has 213 list of variables on the rows side and on the columns side, you have list of 15 vendors which provide those variables.
Client simply would like to know which vendors to buy from starting by the one that has the most variables, then the next one that covers the majority remaining then the next. Client would like to see multiple scenarios of going with every vendor and then design an overlap map
So the task is to produce "any to any" comparison. Basically task is to present multiple scenarios by showing Vendor A variables (indicated by 1 if available or 0 if not. Can be changed to yes/no, or true/false) then showing next vendor maybe B that cam cover most of the remaining variables from vendor A, then vendor C showing again the remaining variables from Vendor A and B.
Then repeating the above with vendors A, then C, then B then D... till closing all 15 vendors
Then restarting the whole process with Vendor B at the center and finding the minimum list of vendors to close needed variables in an iterative manner.
I know this is complicated and I dont even know where to start. I am hoping brilliant minds like yours can propose a solution for that.
if you wish to transpose the data if this makes the process easier that's fine.
peiyezhu
@
samery Are you using Excel for MS365? If so, here's a couple of recursive formulas you could try. However, they will only return the most optimized combination of vendors...
To return a summary of the optimal combination of vendors with their total items covered, try the following formula in any cell (with nothing below it):
=LET( F, LAMBDA(X,head,data,val, LET( a, BYCOL(data, LAMBDA(col, SUM(col))), b, MAX(a), c, XMATCH(b, a), IF(b=0, val, X(X, head, FILTER(data, INDEX(data,, c)=0, 0), VSTACK(val, HSTACK(INDEX(head, c), b)))))), F(F, C1:Q1, C2:Q231, {"Company","Total Covered"}))With your current data, the results should look something like this:
Company Total Covered S&P 138 Oxford eco0mics 28 ECONDB 20 Kpler 11 blue water 5 alphaliner 2 economist intelligence 2 Sinay 1 Oxford Analytica 1 TDM 1 To return a detailed list of the optimal combination of vendors with all of their items covered, try the following formula in any cell (will nothing below it):
=LET( F, LAMBDA(X,head,data,val, LET( a, BYCOL(data, LAMBDA(col, SUM(col))), b, MAX(a), c, XMATCH(b, a), d, INDEX(head, c), IF(b=0, val, X(X, head, FILTER(data, INDEX(data,, c)=0, 0), VSTACK(val, IFNA(HSTACK(d, FILTER(TAKE(data,, 1), INDEX(data,, c)=1)), d)))))), F(F, B1:Q1, B2:Q231, {"Company","Items Covered"}))Finally, to return a list of all items not covered by any vendor, try the following formula in any cell (with nothing below it):
=LET( data, B2:Q231, qty, BYROW(data, LAMBDA(r, SUM(r))), VSTACK("Items Not Covered", FILTER(TAKE(data,, 1), qty=0, "none")))It's a start, anyways. I'll think about it some more and try to find a way to generate other combinations of vendors.
18 Replies
- PeterBartholomew1Silver Contributor
You seem to have more exchanges since I last looked.
What I have tried is a brute force approach of selecting combinations from the vendor list. Ultimately there are 32768 combinations and the 'best' result is simply use all vendors. What I have done is limit the search to 3 or 4 vendors and list the combinations that give the highest variable count.
The combinations are generated by converting a sequence to binary and splitting the bits across the row. I sort that by the count of set bits and truncate the list to give the number of options considered.
- sameryCopper Contributoryour work is very exhaustive and it blew my mind and my team mind. Some people spent 2 days crunching combinations in python and you did it in excel. Kudos to your lovely and excellent work
- peiyezhuBronze ContributorI have downloaded your file.
But only the source table (I guess)。Can you upload an expected result table based on Sheet1 so that I can get what your need easily.
what did you mean :
Client would like to see multiple scenarios of going with every vendor
Do you have any other input criterias besides Sheet1 you shared?
And what is the expected result based on all your inputs (include all criterias and raw dataset)?- sameryCopper Contributorthank you for your kind response.
it's just the table available. Forget about column A, this is just for classification.
Target data columns is the main column containing all 213 variables which my client requires. We asked 15 vendors to see if they have the data and they came back with a yes or no answer which is now reflected on that matrix.
Now client says: It's not enough finding the top match of variables across all 15 vendors. He would like to understand multiple scenarios meaning:
- If I go with first vendor covering let's say 50% of the variables, how many more vendors I require to complete the remaining variables? 2 more? 1 more? 7 more?
- If I go with second vendor.... same question
So the client is saying: present to me a complete analysis so that he can decide not only on coverage and minimum number of vendors but also on other factors which will be added later on such as price maybe, accuracy, and other parameters'.
It could be for example that all variables can be covered by Vendor 7 and Vendor 8 but they happen to be very expensive combined. However going with vendor 3, 9 and 14 could cover all variables too but maybe less expensive and with better feature.
So again client requires multiple scenarios of assessment to make the right conclusion. Hope this helps.
One note I missed in my original post: I think there's 9 or 10 variables that are not covered by any vendors so achieving 100% match is not possible.
and again the result should be a new table looking something like the following:
- Vendor 1 covers 80 variables then combined with Vendor 4 to cover 90 variables...
- Vendor 1 covers 80 variables then combined with vendor 9 covering 50 variables then...
....
- Vendor 2 covering 120 variables with vendor 1 covering 30 variables
In the above example, clearly the function should NOT look for already covered variables of the first vendor in the next vendor and the subsequent ones. For example, if vendor 1 covers tsnuami variables, no need to ask subsequent vendors for tsunami variables, we check with the remaining required variables from the currently full list of variables covered.- djclementsSilver Contributor
samery Just wondering, is the file you provided complete? There currently are no scenarios where all of the variables are covered. If you filter out all of the 1's, you're left with a list of 21 variables that none of the companies are covering.