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.
So here Microsoft is not matching with Google so just Highlight any of the one Microsoft or Google.
Like this.
Solved! Go to Solution.
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 scripts
Excel input
Excel output
Excel for web - create scripts
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.
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 scripts
Excel input
Excel output
Excel for web - create scripts
Added 2 scripts you will need. Let me know if you need help with using them 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 ,
Excel input 1
Excel input 2
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.
@sumurthy , is it possible to create a new file with the not matching values instead of highlighting them?
Episode Seven of Power Platform Connections sees David Warner and Hugo Bernier talk to Dian Taylor, alongside the latest news, product reviews, and community blogs. Use the hashtag #PowerPlatformConnects on social media for a chance to have your work featured on the show.
Super Users – 2023 Season 1 We are excited to kick off the Power Users Super User Program for 2023 - Season 1. The Power Platform Super Users have done an amazing job in keeping the Power Platform communities helpful, accurate and responsive. We would like to send these amazing folks a big THANK YOU for their efforts. Super User Season 1 | Contributions July 1, 2022 – December 31, 2022 Super User Season 2 | Contributions January 1, 2023 – June 30, 2023 Curious what a Super User is? Super Users are especially active community members who are eager to help others with their community questions. There are 2 Super User seasons in a year, and we monitor the community for new potential Super Users at the end of each season. Super Users are recognized in the community with both a rank name and icon next to their username, and a seasonal badge on their profile. Power Apps Power Automate Power Virtual Agents Power Pages Pstork1* Pstork1* Pstork1* OliverRodrigues BCBuizer Expiscornovus* Expiscornovus* ragavanrajan AhmedSalih grantjenkins renatoromao Mira_Ghaly* Mira_Ghaly* Sundeep_Malik* Sundeep_Malik* SudeepGhatakNZ* SudeepGhatakNZ* StretchFredrik* StretchFredrik* 365-Assist* 365-Assist* cha_cha ekarim2020 timl Hardesh15 iAm_ManCat annajhaveri SebS Rhiassuring LaurensM abm TheRobRush Ankesh_49 WiZey lbendlin Nogueira1306 Kaif_Siddique victorcp RobElliott dpoggemann srduval SBax CFernandes Roverandom schwibach Akser CraigStewart PowerRanger MichaelAnnis subsguts David_MA EricRegnier edgonzales zmansuri GeorgiosG ChrisPiasecki ryule AmDev fchopo phipps0218 tom_riha theapurva takolota Akash17 momlo BCLS776 Shuvam-rpa rampprakash ScottShearer Rusk ChristianAbata cchannon Koen5 a33ik Heartholme AaronKnox okeks Matren David_MA Alex_10 Jeff_Thorpe poweractivate Ramole DianaBirkelbach DavidZoon AJ_Z PriyankaGeethik BrianS StalinPonnusamy HamidBee CNT Anonymous_Hippo Anchov KeithAtherton alaabitar Tolu_Victor KRider sperry1625 IPC_ahaas zuurg rubin_boer cwebb365 Dorrinda G1124 Gabibalaban Manan-Malhotra jcfDaniel WarrenBelz Waegemma drrickryp GuidoPreite If an * is at the end of a user's name this means they are a Multi Super User, in more than one community. Please note this is not the final list, as we are pending a few acceptances. Once they are received the list will be updated.
Join us for an in-depth look into the latest updates across Microsoft Dynamics 365 and Microsoft Power Platform that are helping businesses overcome their biggest challenges today. Find out about new features, capabilities, and best practices for connecting data to deliver exceptional customer experiences, collaborating, and creating using AI-powered capabilities, driving productivity with automation—and building towards future growth with today’s leading technology. Microsoft leaders and experts will guide you through the full 2023 release wave 1 and how these advancements will help you: Expand visibility, reduce time, and enhance creativity in your departments and teams with unified, AI-powered capabilities.Empower your employees to focus on revenue-generating tasks while automating repetitive tasks.Connect people, data, and processes across your organization with modern collaboration tools.Innovate without limits using the latest in low-code development, including new GPT-powered capabilities. Click Here to Register Today!
We are excited to share the ‘Power Platform Communities Front Door’ experience with you! Front Door brings together content from all the Power Platform communities into a single place for our community members, customers and low-code, no-code enthusiasts to learn, share and engage with peers, advocates, community program managers and our product team members. There are a host of features and new capabilities now available on Power Platform Communities Front Door to make content more discoverable for all power product community users which includes ForumsUser GroupsEventsCommunity highlightsCommunity by numbersLinks to all communities Users can see top discussions from across all the Power Platform communities and easily navigate to the latest or trending posts for further interaction. Additionally, they can filter to individual products as well. Users can filter and browse the user group events from all power platform products with feature parity to existing community user group experience and added filtering capabilities. Users can now explore user groups on the Power Platform Front Door landing page with capability to view all products in Power Platform. Explore Power Platform Communities Front Door today. Visit Power Platform Community Front door to easily navigate to the different product communities, view a roll up of user groups, events and forums.
We are so excited to see you for the Microsoft Power Platform Conference in Las Vegas October 3-5 2023! But first, let's take a look back at some fun moments and the best community in tech from MPPC 2022 in Orlando, Florida. Featuring guest speakers such as Charles Lamanna, Heather Cook, Julie Strauss, Nirav Shah, Ryan Cunningham, Sangya Singh, Stephen Siciliano, Hugo Bernier and many more. Register today: https://www.powerplatformconf.com/
User | Count |
---|---|
13 | |
13 | |
12 | |
11 | |
8 |
User | Count |
---|---|
27 | |
23 | |
20 | |
19 | |
19 |