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

Compare 2 excel sheets and highlight which values are not matching.

Hi all,
I need to create a flow where i compare 2 excel files  and check if they are same, if not same  changing the font color or making the font bigger of the non-matching values in the any of the one excel file would be helpful to identify which all values are not matching.

sabeoleonunes_0-1602672843986.png

 

sabeoleonunes_1-1602672889809.png

So here Microsoft is not matching with Google so just Highlight any of the one Microsoft or Google.

sabeoleonunes_2-1602672957509.png

Like this.

2 ACCEPTED SOLUTIONS

Accepted Solutions
sumurthy
Employee
Employee

This scenario can be accomplished using "Run script" action on Excel online flow. It requires creation of 2 Office Scripts (TypeScript scripts from Excel for web). More details are here: 

https://docs.microsoft.com/en-us/office/dev/scripts/develop/power-automate-integration 

 

For your scenario, here's how I'd go about it - 

(Assuming you only want to do comparison in file-2. If you need to highlight in file-1, simply repeat steps by switching files)

1. Trigger > 

2. Write a script that returns the values from your worksheet/or table from File-1. Return unique values of companies. Run this as part of "run script action"

3. Pass that as input to second script, which then compares/looks-up against the input unique list of values being passed against File-2 and if not found will use the APIs to highlight the cell. 

 

// Script named: Return unique companies

// Run this against source file containing company names. Assumes Sheet1 and a table within it containing "Company" column. Change as per need. 

 

function main(workbook: ExcelScript.Workbook) {
    // Your code here
    let mySheet = workbook.getWorksheet('Sheet1');
    let table = mySheet.getTables()[0];
    let data2D = table.getColumnByName('Company').getRangeBetweenHeaderAndTotal().getValues();
    let companies = data2D.map(row => row[0]);
    
  let uniqueCompanies = companies.filter(function (item, pos) {
    return companies.indexOf(item) == pos;
  })
  console.log(uniqueCompanies.join('|'))
  return uniqueCompanies.join('|'); 
}

 

 

// Script named: Highlight missing companies

// Run this against target file where you want to highlight. Assumes Sheet1 and a table within it containing "Company" column. Change as per need. 

function main(workbook: ExcelScript.Workbook, uniqCompaniesStr: string) {
  uniqCompaniesStr = 'Microsoft|Google|Netflix|Apple'
  let uniqCompanies = uniqCompaniesStr.split('|');
  console.log(uniqCompanies);

  let mySheet = workbook.getWorksheet('Sheet8');

  let table = mySheet.getTables()[0];
  // First clear all formats
  table.getRange().clear(ExcelScript.ClearApplyTo.formats); 
  let dataRange = table.getColumnByName('Company').getRangeBetweenHeaderAndTotal();
  let companies = dataRange.getValues();
  for (let i=0; i< companies.length; i++) {    
    let row = companies[i]
    if (uniqCompanies.indexOf(row[0]) < 0) {
      // console.log("Not found: " + row[0] + " at: " + i)
      dataRange.getCell(i,0).getFormat().getFill().setColor('Yellow');
    }
  }
  return;  
}

 

Save above scripts in your Office Scripts and run this in Power Automate using "Run Script". 

 

PA flow with 2 scriptsPA flow with 2 scriptsExcel inputExcel inputExcel outputExcel outputExcel for web - create scriptsExcel for web - create scripts

View solution in original post

Passing multiple columns may be easier if you return an object out of the 1st script. It'll help you with comparison in the next script. But the flow and logic will remain identical. 

View solution in original post

8 REPLIES 8
sumurthy
Employee
Employee

This scenario can be accomplished using "Run script" action on Excel online flow. It requires creation of 2 Office Scripts (TypeScript scripts from Excel for web). More details are here: 

https://docs.microsoft.com/en-us/office/dev/scripts/develop/power-automate-integration 

 

For your scenario, here's how I'd go about it - 

(Assuming you only want to do comparison in file-2. If you need to highlight in file-1, simply repeat steps by switching files)

1. Trigger > 

2. Write a script that returns the values from your worksheet/or table from File-1. Return unique values of companies. Run this as part of "run script action"

3. Pass that as input to second script, which then compares/looks-up against the input unique list of values being passed against File-2 and if not found will use the APIs to highlight the cell. 

 

// Script named: Return unique companies

// Run this against source file containing company names. Assumes Sheet1 and a table within it containing "Company" column. Change as per need. 

 

function main(workbook: ExcelScript.Workbook) {
    // Your code here
    let mySheet = workbook.getWorksheet('Sheet1');
    let table = mySheet.getTables()[0];
    let data2D = table.getColumnByName('Company').getRangeBetweenHeaderAndTotal().getValues();
    let companies = data2D.map(row => row[0]);
    
  let uniqueCompanies = companies.filter(function (item, pos) {
    return companies.indexOf(item) == pos;
  })
  console.log(uniqueCompanies.join('|'))
  return uniqueCompanies.join('|'); 
}

 

 

// Script named: Highlight missing companies

// Run this against target file where you want to highlight. Assumes Sheet1 and a table within it containing "Company" column. Change as per need. 

function main(workbook: ExcelScript.Workbook, uniqCompaniesStr: string) {
  uniqCompaniesStr = 'Microsoft|Google|Netflix|Apple'
  let uniqCompanies = uniqCompaniesStr.split('|');
  console.log(uniqCompanies);

  let mySheet = workbook.getWorksheet('Sheet8');

  let table = mySheet.getTables()[0];
  // First clear all formats
  table.getRange().clear(ExcelScript.ClearApplyTo.formats); 
  let dataRange = table.getColumnByName('Company').getRangeBetweenHeaderAndTotal();
  let companies = dataRange.getValues();
  for (let i=0; i< companies.length; i++) {    
    let row = companies[i]
    if (uniqCompanies.indexOf(row[0]) < 0) {
      // console.log("Not found: " + row[0] + " at: " + i)
      dataRange.getCell(i,0).getFormat().getFill().setColor('Yellow');
    }
  }
  return;  
}

 

Save above scripts in your Office Scripts and run this in Power Automate using "Run Script". 

 

PA flow with 2 scriptsPA flow with 2 scriptsExcel inputExcel inputExcel outputExcel outputExcel for web - create scriptsExcel for web - create scripts

Hi @sumurthy ,
Can you please post the script.

Added 2 scripts you will need. Let me know if you need help with using them in power automate.

Hi @sumurthy 

Can you please help me to execute this in Power Automate.

Done, see above screenshots in the original response. 

If it works for you, please accept the answer. 

If it doesn't work, please email and we can discuss offline.

 

Quick note - if you don't see the "Automate" tab in Excel for web (see my screenshot), please have your O365 Admin turn on Office Scripts. See here for details: https://docs.microsoft.com/en-us/microsoft-365/admin/manage/manage-office-scripts-settings?view=o365...

 

Within few weeks we should have it rolled out to all users (non GCC) by default.

Hi @sumurthy ,

The above scripts worked completely fine, and I was able to get the non-matching values colored.
Just wanted to know , if there are more then then 2-3 columns to compare how will the script be ,

sabeoleonunes_0-1602823926931.png

Excel input 1

sabeoleonunes_1-1602823955470.png

Excel input 2

sabeoleonunes_2-1602823986090.png

Excel Output

And do we always need to pass the input data in the script?

Thanks.



Passing multiple columns may be easier if you return an object out of the 1st script. It'll help you with comparison in the next script. But the flow and logic will remain identical. 

raash
New Member

@sumurthy , is it possible to create a new file with the not matching values instead of highlighting them?

Helpful resources

Announcements

Announcing Power Apps Copilot Cookbook Gallery

We are excited to share that the all-new Copilot Cookbook Gallery for Power Apps is now available in the Power Apps Community, full of tips and tricks on how to best use Microsoft Copilot as you develop and create in Power Apps. The new Copilot Cookbook is your go-to resource when you need inspiration--or when you're stuck--and aren't sure how to best partner with Copilot while creating apps.   Whether you're looking for the best prompts or just want to know about responsible AI use, visit Copilot Cookbook for regular updates you can rely on--while also serving up some of your greatest tips and tricks for the Community. Our team will be reviewing posts using the new "Copilot" label to ensure we highlight and amplify the most relevant and recent content, so you're assured of high-quality content every time you visit. If you share a post that gets featured in the curated gallery, you'll get a PM in the Community to let you know!The curated gallery is ready for you to experience now, so visit the new Copilot Cookbook for Power Apps today: Copilot Cookbook - Power Platform Community. We can't wait to see what you "cook" up!    

Tuesday Tips: Getting Started in the Community

TUESDAY TIPS is back!   This weekly series of posts is our way of sharing helpful things we've learned or shared that have helped members of the Community. Whether you're just getting started or you're a seasoned pro, Tuesday Tips will help you know where to go, what to look for, and navigate your way through the ever-growing--and ever-changing--world of the Power Platform Community! The original run of Tuesday Tips was a highlight of last year, and these all-new Tips will hopefully prove to be just as informative as helpful. We will cover some basics about the Community, a few "insider tips" to make your experience even better, and sharing best practices gleaned from our most active community members and Super Users. Make sure to watch the News & Announcements each week for the latest and greatest Tuesday Tips!   THIS WEEK: I'm Brand New! What Do I Do? The number of new community members we have each week is pretty amazing, and we are so glad to welcome all of you to the Community! You may be wondering. "What do I do? Where do I get started? Will anyone be willing to help me? What I have a question? Help!"   Let's start with this: Welcome to the low-code revolution, and more importantly, welcome to the Power Platform Community! This is a great place to start. Whether you're busy with Power Apps, getting familiar with Power Automate, engaging Copilot Studio, or building in Power Pages, there are a few key places you should check out as you begin your journey: FORUMS: The forums are THE place to ask questions, look at questions asked by other Community members—and see answers and solutions from our Super Users and other helpful people in the Community. Power Apps ForumsPower Automate ForumsCopilot Studio ForumsPower Pages Forums   NEWS & ANNOUNCEMENTS: Our News & Announcements section highlights the newest and greatest updates in the Community, news from the product team, and so much more. It’s updated a few times each week and will also help you find ways to connect with what’s going on in the ever-growing world of Power Platform. Power Apps News & AnnouncementsPower Automate News & AnnouncementsCopilot Studio News & AnnouncementsPower Pages News & Announcements   GALLERIES: The Galleries section of the Community features tons of tips and tricks, features and benefits, and more—through videos created by our Super Users, product teams, and other helpful members of the Community. Power Apps GalleriesPower Automate Galleries Copilot Studio GalleriesPower Pages Galleries BLOGS: The community blogs section is full of handy step-by-step tips from members of the Community—and some of them include detailed answers to some of the questions most frequently asked questions, as well as how they solved a problem they faced. Power Apps Community BlogPower Automate Community BlogCopilot Studio Community BlogPower Pages Community Blog POWER UP PROGRAM: If you’d like to really take a huge step forward in your journey, we recommend checking out the Power Up Program, a Microsoft-sponsored initiative that trains new Power Platform users and has been a huge success since it launched a little over a year ago. There’s a waiting list, so definitely apply soon if you’re interested! Find out more here: Microsoft Power Up Program for career switchers.   There's so much more you'll discover in your Power Platform experience, and this Community is here for YOU! We are glad you've discovered us and can't wait to see where you grow! If you're new to the Community and just getting started, make sure to give this post a kudo and introduce yourself so we can welcome you!

Super User of the Month | Drew Poggemann

As part of a new monthly feature in the Community, we are excited to share that Drew Poggemann is our featured Super User for the month of February 2024. If you've been in the Community for a while, we're sure Drew's name is familiar to you, as he is one of our most active contributors--he's been a Super User for five consecutive seasons!   Since authoring his first reply 5 years ago to his 514th solution authored, Drew has helped countless Community members with his insights and expertise. In addition to being a Super User, Drew is also a User Group leader and a Microsoft MVP. His contributions to our Super User sessions and to the new SUIT program are always welcome--as well as his sense of humor and fun-loving way of sharing what he knows with others.   When Drew is not solving problems and authoring solutions, he's busy overseeing the Solution Architecture team at HBS, specializing in application architecture and business solution strategy--something he's been doing for over 30 years. We are grateful for Drew and the amazing way he has used his talent and skills to help so many others in the Community. If you are part of the SUIT program, you got to hear some great tips from Drew at the first SUIT session--and we know he still has much more to share!You can find him in the Community and on LinkedIn. Thank you for all you do, Drew!

Celebrating a New Season of Super Users with Charles Lamanna, CVP Microsoft Business Applications

February 8 was the kickoff to the 2024 Season One Super User program for Power Platform Communities, and we are thrilled to welcome back so many returning Super Users--as well as so many brand new Super Users who started their journey last fall. Our Community Super Users are the true heroes, answering questions, providing solutions, filtering spam, and so much more. The impact they make on the Communities each day is significant, and we wanted to do something special to welcome them at our first kickoff meeting of the year.   Charles Lamanna, Microsoft CVP of Business Applications, has stressed frequently how valuable our Community is to the growth and potential of Power Platform, and we are honored to share this message from him to our 2024 Season One Super Users--as well as anyone who might be interested in joining this elite group of Community members.     If you want to know more about Super Users, check out these posts for more information today:    Power Apps: What is A Super User? - Power Platform CommunityPower Automate: What is A Super User? - Power Platform Community Copilot Studio: What is A Super User? - Power Platform Community Power Pages: What is A Super User? - Power Platform Community

Super Users 2024 Season One is Here!

   We are excited to announce the first season of our 2024 Super Users is here! Our kickoff to the new year welcomes many returning Super Users and several new faces, and it's always exciting to see the impact these incredible individuals will have on the Community in 2024! We are so grateful for the daily difference they make in the Community already and know they will keep staying engaged and excited for all that will happen this year.   How to Spot a Super User in the Community:Have you ever written a post or asked for help in the Community and had it answered by a user with the Super User icon next to their name? It means you have found the actual, real-life superheroes of the Power Platform Community! Super Users are our heroes because of the way they consistently make a difference in the Community. Our amazing Super Users help keep the Community a safe place by flagging spam and letting the Community Managers know about issues. They also make the Community a great place to find answers, because they are often the first to offer solutions and get clarity on questions. Finally, Super Users share valuable insights on ways to keep the Community growing, engaging, and looking ahead!We are honored to reveal the new badges for this season of Super Users! Congratulations to all the new and returning Super Users!     To better answer the question "What is a Super User?" please check out this article: Power Apps: What is A Super User? - Power Platform CommunityPower Automate: What is A Super User? - Power Platform Community Copilot Studio: What is A Super User? - Power Platform Community Power Pages: What is A Super User? - Power Platform Community

Microsoft Power Platform | 2024 Release Wave 1 Plan

Check out the latest Microsoft Power Platform release plans for 2024!   We have a whole host of exciting new features to help you be more productive, enhance delegation, run automated testing, build responsive pages, and so much more.    Click the links below to see not only our forthcoming releases, but to also try out some of the new features that have recently been released to market across:     Power Apps  Power Automate  Copilot Studio   We can’t wait to share with you all the upcoming releases that will help take your Power Platform experience to the next level!    Check out the entire Release Wave: Power Platform Complete Release Planner 

Users online (2,760)