cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
devaaron
Helper III
Helper III

comparison of two excel files for matching information

There are two excel files A and B that I need to make sure information is matching.

 

The first task I need to filter out column reference for specific value (let’s say there are X, y, z and we want only Xs) then sum up the total amount for value Xs Amount column (their prices) maybe in a new total column or something. How can we sum up the total values for specifically X values? I liked to call it the first total amount.

Screen Shot 2021-03-31 at 8.54.55 PM.png

 

 

 

Then in the same file check the reference numbers (which is multiple for some rows lets says 3) and make all of these into one row as combined List. How do we list them? into one column. 

 

By looking at the list we created in previous step I would like to check if reference numbers list in the file A is matching in the excel file B. If the list of reference numbers from file A is matching in file B as Item number then add these item number's amount into second total column (which is also sum up the amount). but if the reference numbers from file A and B does not match I like to create a new column or list for those missing numbers where can be check where is it missing. 

 

 

Screen Shot 2021-03-31 at 8.56.59 PM.png

 

Could you please consider that these files will be consisting thousands of rows I believe it's important as 'for each' sometimes it get exhausted to do.  

 

Thank you very much in advance. 

 

1 ACCEPTED SOLUTION

Accepted Solutions

Ok, thanks for the example it's much clearer now!

 

For this you need two scripts since there are two separate files. This first one sums up the Reference Aamounts and creates the Ref No List and returns all of those numbers back to Power Automate. You need to pass in the sheet name, table name, and reference string you want to use.

 

function main(workbook: ExcelScript.Workbook, sheetName: string, tableName: string, reference: string): string[] {
  const tbl = workbook.getWorksheet(sheetName).getTable(tableName);
  const rowCount = tbl.getRowCount();
  const values = tbl.getRangeBetweenHeaderAndTotal().getValues();
  const referenceIndex = 0;
  const amountIndex = 1;

  const totalAmount = values.filter((value) => value[referenceIndex] === reference).reduce((total, current) => total + (current[amountIndex] as number), 0);
  tbl.getRange().getLastRow().getCell(2, amountIndex).setValue(`Total1=$${totalAmount}`);

  const ref1Index = 2;
  const ref2Index = 3;
  const ref3Index = 4;

  const refList = values.map((value) => {
    if (value[referenceIndex] === reference) {
      return [value[ref1Index], value[ref2Index], value[ref3Index]].filter((ref) => !!ref).join(', ');
    } else {
      return '';
    }
  });
  tbl.addColumn(-1, ['Ref No List'].concat(refList));

  // Format refList into an array of single strings.
  return [].concat(...refList.filter((ref) => ref.trim() !== '').map((ref) => ref.split(', ')));
}

 

This second script sums up the Item No Amounts and creates the Missing Item No and Amount of Missing columns. You just need to pass in the sheet and table you want to operate on as well as the returned list of reference numbers from the first script.

 

function main(workbook: ExcelScript.Workbook, sheetName: string, tableName: string, referenceList: string[]) {
  const tbl = workbook.getWorksheet(sheetName).getTable(tableName);
  const values = tbl.getRangeBetweenHeaderAndTotal().getValues();
  const itemNoIndex = 0;
  const amountIndex = 1;

  const totalAmount = values.filter((value) => referenceList.includes(value[itemNoIndex] as string)).reduce((total, current) => total + (current[amountIndex] as number), 0);
  tbl.getRange().getLastRow().getCell(2, amountIndex).setValue(`Total2=$${totalAmount}`);

  let missingItemNos = values.filter((value) => !referenceList.includes(value[itemNoIndex] as string)).map((value) => value[itemNoIndex] as string);
  let missingItemNoAmounts = values.filter((value) => !referenceList.includes(value[itemNoIndex] as string)).map((value) => `$${value[amountIndex]}`);
  const foundItemsCount = tbl.getRowCount() - missingItemNos.length;
  missingItemNos = missingItemNos.concat(Array(foundItemsCount).fill(''));
  missingItemNoAmounts = missingItemNoAmounts.concat(Array(foundItemsCount).fill(''));
  tbl.addColumn(-1, ['Missing Item No'].concat(missingItemNos));
  tbl.addColumn(-1, ['Amount Of Missing'].concat(missingItemNoAmounts));
}

 

 

View solution in original post

15 REPLIES 15
mahoneypat
Solution Sage
Solution Sage

This would be more easily done in Power BI.  What will you do with the data once all those steps are completed?

Regards,

Pat

GeoffRen
Microsoft
Microsoft

I would recommend using Office Scripts, specifically Office Scripts with Power Automate. This is the 'Run Script' action on the Excel connector. With Office Scripts you can use the 'Run Script' action to execute javascript against a workbook. So you can write a script that does exactly what you stated with essentially no boundaries on the logic you want. You would also want to use Office Scripts to retrieve the list of reference numbers to compare with rather than using the other ExcelOnline actions since they'll be too slow to apply to all of your rows. If you want to go this route and want help, I can help provide a script that you can start with.

Hi,

I like it to update excel files like make the changes. But how will I know if it get an issue within power BI. Cause power automate can give notification incase something wrong via email.

Hi,

Yes please. Thanks

Using the example table you gave can you post at least three more pictures, one for the output of each step? It'd help greatly with clarity. I don't understand exactly where you want the X sum to be written to or what you want to do with the reference numbers.

Hi,

so if the reference value is x, i like the amounts to added and make a sum amount for it (can be new column and we can call it total 1) then for these X values' the reference numbers will be in the one list as you can see there are more than one reference numbers for x values sometimes (the reason for that is to make comparison easier from excel1 file to excel2 file we can call this list 1).

 

Then we can make a loop list 1 from excel 1 to check for each reference number in excel 2 if they do not match (the reference number) then check item number column to see if they are matching with list1 and if they are matching we will add all the amounts equal to item number adds into second total as a column or sum. 

 

For the missing reference numbers which are not matching we can make another column to put all these missing reference numbers from excel 1 to excel 2. 

 

**Note second excel file have multiple sheets in it lets say the one we work called secondSheet. 

 

I hope this helps with more clarity. Let me know if you need more info. 

 

Thank you very much.

Sorry, there's a lot of questions I have about what your scenario that can easily be answered with picture examples of your tables before and after the processing happens. For example, is the x value a running or single cumulative sum, what is the format of the table in the second excel file (your example table doesn't have reference numbers and you gives steps to "check for each reference number" and to "check item number column"), what are you adding in the second table (not clear to me, do you want all the amounts added together as a cumulative sum once or a running sum), and others.

 

Can you provide an example that shows all the data interactions you want? And can you do this for your tables before any processing and examples of the same tables after the processing? 

Hi GeoffRen,

 

Sorry for the confusion. I have attached the tables hopefully it will clarify even more of your questions.

Screen Shot 2021-04-02 at 3.24.31 PM.png

The table above are two different excel file. The first table at the top is excel1 and the bottom one is excel2. 

 

Solution table image:

Screen Shot 2021-04-02 at 3.24.40 PM.png

The table above is the solution that I would like to achieve. The first solution table is called excel1 and need the total of the Xs's sum and all the references number list into a new column called "Ref No List" please. 

 

The bottom solution table is another excel file but has multiple worksheet within the file, I would like to check only worksheet secondSheet. As you can see there's a column called "Item No" where I would like to be able to compared the values with excel 1. "Item No" and "Ref No List" are the same thing just making the comparison between the two file. 

 

If you have any more questions, please feel free to ask and I will try my best to explain or show it on a table format. 

 

Best regards

Aaron

 

Ok, thanks for the example it's much clearer now!

 

For this you need two scripts since there are two separate files. This first one sums up the Reference Aamounts and creates the Ref No List and returns all of those numbers back to Power Automate. You need to pass in the sheet name, table name, and reference string you want to use.

 

function main(workbook: ExcelScript.Workbook, sheetName: string, tableName: string, reference: string): string[] {
  const tbl = workbook.getWorksheet(sheetName).getTable(tableName);
  const rowCount = tbl.getRowCount();
  const values = tbl.getRangeBetweenHeaderAndTotal().getValues();
  const referenceIndex = 0;
  const amountIndex = 1;

  const totalAmount = values.filter((value) => value[referenceIndex] === reference).reduce((total, current) => total + (current[amountIndex] as number), 0);
  tbl.getRange().getLastRow().getCell(2, amountIndex).setValue(`Total1=$${totalAmount}`);

  const ref1Index = 2;
  const ref2Index = 3;
  const ref3Index = 4;

  const refList = values.map((value) => {
    if (value[referenceIndex] === reference) {
      return [value[ref1Index], value[ref2Index], value[ref3Index]].filter((ref) => !!ref).join(', ');
    } else {
      return '';
    }
  });
  tbl.addColumn(-1, ['Ref No List'].concat(refList));

  // Format refList into an array of single strings.
  return [].concat(...refList.filter((ref) => ref.trim() !== '').map((ref) => ref.split(', ')));
}

 

This second script sums up the Item No Amounts and creates the Missing Item No and Amount of Missing columns. You just need to pass in the sheet and table you want to operate on as well as the returned list of reference numbers from the first script.

 

function main(workbook: ExcelScript.Workbook, sheetName: string, tableName: string, referenceList: string[]) {
  const tbl = workbook.getWorksheet(sheetName).getTable(tableName);
  const values = tbl.getRangeBetweenHeaderAndTotal().getValues();
  const itemNoIndex = 0;
  const amountIndex = 1;

  const totalAmount = values.filter((value) => referenceList.includes(value[itemNoIndex] as string)).reduce((total, current) => total + (current[amountIndex] as number), 0);
  tbl.getRange().getLastRow().getCell(2, amountIndex).setValue(`Total2=$${totalAmount}`);

  let missingItemNos = values.filter((value) => !referenceList.includes(value[itemNoIndex] as string)).map((value) => value[itemNoIndex] as string);
  let missingItemNoAmounts = values.filter((value) => !referenceList.includes(value[itemNoIndex] as string)).map((value) => `$${value[amountIndex]}`);
  const foundItemsCount = tbl.getRowCount() - missingItemNos.length;
  missingItemNos = missingItemNos.concat(Array(foundItemsCount).fill(''));
  missingItemNoAmounts = missingItemNoAmounts.concat(Array(foundItemsCount).fill(''));
  tbl.addColumn(-1, ['Missing Item No'].concat(missingItemNos));
  tbl.addColumn(-1, ['Amount Of Missing'].concat(missingItemNoAmounts));
}

 

 

View solution in original post

Before tables:

 

GeoffRen_1-1617394363530.png

 

GeoffRen_0-1617394350817.png

 

After tables:

GeoffRen_5-1617394867112.png

 

Hi,

Its looking great although I see in the after tables we are getting Y values as well in total and missing. We need to compare and get total and missing only with X values . Could we make that happen?

 

Thank you very much.

 

Where do you see Y values in total? In my tests (so the tables I posted), only the X values are used. That is, 1 + 52 + 3457 = 3510 and 12.30 + 23.40 + 34.50 = 70.20. Also do you not want the Y values in missing? In your example the things listed in the new Missing Item No column are just the things that exist in the Item No column but don't exist in the Ref No List column. Is that incorrect? Is there other logic you would like there?

Hi,

in the first after table I saw Y value, this is why I have mentioned. I do not need Y values for missing or total.

 

Thank you very much.

The Y values are not being used for missing or total. The two after tables I have are the results of running the scripts on the two before tables. So the after tables are the same as the before tables with more stuff added to them. Can you further specify your needs? So do you want:

1. new data added to the old tables (as is currently in place)

2. new tables created with the extracted data

3. new data added to the old tables with the non-x values deleted from both tables

Hi GeoffRen

 

Sorry for the late reply. The problem has been solved and I've accepted the solution that you have provided. It was very helpful thank you for your help.

 

Best regards

Aaron

Helpful resources

Announcements
MPA_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

V3_PVA CAmpaign Carousel.png

Community Challenge - Giveaways!

Participate in the Power Virtual Agents Community Challenge

Carousel 2021 Release Wave 2 Plan 768x460.jpg

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

R2 (Green) 768 x 460px.png

Microsoft Dynamics 365 & Power Platform User Professionals

DynamicsCon is a FREE, 4 half-day virtual learning experience for 11,000+ Microsoft Business Application users and professionals.

Top Solution Authors
Users online (2,007)