I'm using Office Scripts and it's been going well, until now that I have to copy some information from one workbook, to another workbook... I can copy from one to another normally, but can't record with office scripts, looked around for some codes that does something similar, but had no luck, maybe you can help me with some ideas.
Solved! Go to Solution.
Hi @victor_lion ,
Sorry for I'm afraid that the scripts is not supported in Microsoft flow currently.
Best Regards,
Alice
Community Support Team _ Alice Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @victor_lion could you please provide a picture of your flow in edit mode?
Maybe it is due to some sort of limitation, have you checked this documentation?
Thank you.
Hi @victor_lion ,
Sorry for I'm afraid that the scripts is not supported in Microsoft flow currently.
Best Regards,
Alice
Community Support Team _ Alice Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
I'm using only a execute script, with manual start... This first script does just some edditing on text, puts filters, creates sheets and things like that.
Now I'm at a point where I have two excel archives, one that have several formulas, and the other with the data.
Hi @victor_lion ,
Unfortunately at this moment, Office Scripts doesn't support cross workbook operations yet. Please share your feedback on the following channels to make sure your voice heard. Thanks!
As a workaround, you can probably write two scripts to achieve similar goal:
Hope this helps!
Yutao
Hi @Yutao !
I think this might work, but I how can I send data between the workbooks?
Here is one possible approach -
Firstly we'll need two scripts:
Script: "Export range"
function main(workbook: ExcelScript.Workbook, sheetName: string, rangeAddress: string): string {
let sheet = workbook.getWorksheet(sheetName);
let range = sheet.getRange(rangeAddress);
return JSON.stringify(range.getValues());
}
Script: "Import range:
function main(workbook: ExcelScript.Workbook, sheetName: string, rangeAddress: string, values: string) {
let sheet = workbook.getWorksheet(sheetName);
let range = sheet.getRange(rangeAddress);
range.setValues(JSON.parse(values));
}
Please note right now there is an issue with directly returning "string[ ][ ]" (return type of "range.getValues( )") from an Office Scripts function, so here I have to work around it by converting to string with JSON.stringify in the exporter and convert it back to "string[ ][ ]" with JSON.parse in the importer.
Here is the fictional flow that will copy data from A1:C4 on Sheet 1 of the first workbook to A1:C4 on Sheet1 of the second workbook.
One limitation though, "range.getValues( )" only takes the content of string/number/boolean so all the formatting and formula will be lost. If you want to retrieve more stuff like formatting, formulas, etc., you'll probably need to write some more complex code with things like "range.getFormat", "range.getFormula", "range.setFormula", etc.
Yutao
Thanks for the help @Yutao , I'm new to javascript, so I'm feeling kinda lost...
I want to perform search in the script, and then select all the rows on the sheet, starting from the cell I've searched for.
// Find first 3.1.1 on Sheet1
selectedSheet.getRange("B1048576")
.find("3.1.1", {
completeMatch: false,
matchCase: false,
searchDirection: ExcelScript.SearchDirection.forward
});
Using this code, but then I don't know how to proceed...
Let's say your worksheet contains data in range A1:M100. And cell A10 contains "3.1.1". So you only want to grab the data in range A10:M100, right?
If this is the case, wondering if you could try something like this:
function main(workbook: ExcelScript.Workbook): string {
let sheet = workbook.getWorksheet("Sheet2");
let usedRange = sheet.getUsedRange();
let found = usedRange.find("3.1.1", {
completeMatch: false,
matchCase: false,
searchDirection: ExcelScript.SearchDirection.forward
});
let selected = sheet.getRangeByIndexes(
found.getRowIndex(),
found.getColumnIndex(),
usedRange.getLastRow().getRowIndex() - found.getRowIndex() + 1,
usedRange.getLastColumn().getColumnIndex() - found.getColumnIndex() + 1);
return JSON.stringify(selected.getValues());
}
This script will copy the text value from the rows starting from the row containing "3.1.1" till the last row that contains data on the sheet.
Hope this helps!
Yutao
Thanks @Yutao .
I wanted to know if instead of hardcoding range in the second script, how can I implement getSurroundingRegion() or any other method to dynamically determine table size being passed from first script.
Hi @georgechitechi -
Wondering if the below solution would work for your case.
The exporter script, which will return the values (a two-dimensional string array) of the range surrounding a starting cell:
function main(Workbook: ExcelScript.Workbook, sheetName: string, address: string) {
let range = Workbook.getWorksheet(sheetName).getRange(address);
let surroundingRegion = range.getSurroundingRegion();
let values = surroundingRegion.getValues();
return values;
}
The importer script, which will first calculate the size of the target range based on the input two-dimensional string array and set the values for the target range:
function main(Workbook: ExcelScript.Workbook, sheetName: string, address: string, values: string[][]) {
let range = Workbook.getWorksheet(sheetName).getRange(address);
if (values.length === 0) {
return;
}
let resizedRange = range.getAbsoluteResizedRange(values.length, values[0].length);
resizedRange.setValues(values);
}
The exporter action and the importer action:
Please note in order for the Import action to take the entire array from the Export action's output as the input, you'll need to switch the Import action's input to use the entire array - click on the highlighted button in the picture:
Hope this helps!
Hi @Yutao
How can i use range.getFormat together with the range.getValues() in the Script: "Export range" ?
Because during the process, some cells with numbers were convert from "23795871000004600003381260064996204000006754" to "2,37958710000046E+43"
Can u help me?
I'm not sure if there is an easy way to include both the range data values and number formats in a single API call.
I guess one workaround is to probably call range.getValues() and range.getNumberFormats() to export an array for data and another array for number formats from the exporter; then let the importer script accept that two arrays and apply both of them to the target range through range.setValues() and range.setNumberFormats().
Hi @Yutao this script looks like what I need to copy data from worksheet to another workbook.
I have set up the flow, and your 'exporter' script runs for me without errors, and I can see the data from the sheet in the run history.
But when I run 'importer' script I get an error on the output related to line 2 'get range'. Could you tell me what I need to look for to correct this error. What exactly should go in address parameter field of import script...my understanding was your script is creating this dynamically or maybe I have misunderstood? I have tried different values eg J10 like in your example
I realized my mistake, I needed to first create the sheet name in destination workbook. Thank you for script, very useful!
Hi Yutao,
It seems it doesn't show 'result' dynamic content for me, what could be the issue?
Thanks!
Hi, when use your code with more than 1000 rows, it send me "Range setValues: Timeout". How can I solve this? Thanks!
@Anonymous - there are indeed some perf consequences when working with large datasets. Is it possible to split the imported ranges into smaller chunks, e.g., 250 rows each and make four separate Range.setValues calls?
Dear Community Members, We'd like to let you know of an upcoming change to the community platform: starting July 16th, the platform will transition to a READ ONLY mode until July 22nd. During this period, members will not be able to Kudo, Comment, or Reply to any posts. On July 22nd, please be on the lookout for a message sent to the email address registered on your community profile. This email is crucial as it will contain your unique code and link to register for the new platform encompassing all of the communities. What to Expect in the New Community: A more unified experience where all products, including Power Apps, Power Automate, Copilot Studio, and Power Pages, will be accessible from one community.Community Blogs that you can syndicate and link to for automatic updates. We appreciate your understanding and cooperation during this transition. Stay tuned for the exciting new features and a seamless community experience ahead!
We are excited to announce the Summer of Solutions Challenge! This challenge is kicking off on Monday, June 17th and will run for (4) weeks. The challenge is open to all Power Platform (Power Apps, Power Automate, Copilot Studio & Power Pages) community members. We invite you to participate in a quest to provide solutions to as many questions as you can. Answers can be provided in all the communities. Entry Period: This Challenge will consist of four weekly Entry Periods as follows (each an “Entry Period”) - 12:00 a.m. PT on June 17, 2024 – 11:59 p.m. PT on June 23, 2024 - 12:00 a.m. PT on June 24, 2024 – 11:59 p.m. PT on June 30, 2024 - 12:00 a.m. PT on July 1, 2024 – 11:59 p.m. PT on July 7, 2024 - 12:00 a.m. PT on July 8, 2024 – 11:59 p.m. PT on July 14, 2024 Entries will be eligible for the Entry Period in which they are received and will not carryover to subsequent weekly entry periods. You must enter into each weekly Entry Period separately. How to Enter: We invite you to participate in a quest to provide "Accepted Solutions" to as many questions as you can. Answers can be provided in all the communities. Users must provide a solution which can be an “Accepted Solution” in the Forums in all of the communities and there are no limits to the number of “Accepted Solutions” that a member can provide for entries in this challenge, but each entry must be substantially unique and different. Winner Selection and Prizes: At the end of each week, we will list the top ten (10) Community users which will consist of: 5 Community Members & 5 Super Users and they will advance to the final drawing. We will post each week in the News & Announcements the top 10 Solution providers. At the end of the challenge, we will add all of the top 10 weekly names and enter them into a random drawing. Then we will randomly select ten (10) winners (5 Community Members & 5 Super Users) from among all eligible entrants received across all weekly Entry Periods to receive the prize listed below. If a winner declines, we will draw again at random for the next winner. A user will only be able to win once overall. If they are drawn multiple times, another user will be drawn at random. Individuals will be contacted before the announcement with the opportunity to claim or deny the prize. Once all of the winners have been notified, we will post in the News & Announcements of each community with the list of winners. Each winner will receive one (1) Pass to the Power Platform Conference in Las Vegas, Sep. 18-20, 2024 ($1800 value). NOTE: Prize is for conference attendance only and any other costs such as airfare, lodging, transportation, and food are the sole responsibility of the winner. Tickets are not transferable to any other party or to next year’s event. ** PLEASE SEE THE ATTACHED RULES for this CHALLENGE** Week 1 Results: Congratulations to the Week 1 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Community MembersNumber SolutionsSuper UsersNumber Solutions Deenuji 9 @NathanAlvares24 17 @Anil_g 7 @ManishSolanki 13 @eetuRobo 5 @David_MA 10 @VishnuReddy1997 5 @SpongYe 9JhonatanOB19932 (tie) @Nived_Nambiar 8 @maltie 2 (tie) @PA-Noob 2 (tie) @LukeMcG 2 (tie) @tgut03 2 (tie) Week 2 Results: Congratulations to the Week 2 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Week 2: Community MembersSolutionsSuper UsersSolutionsPower Automate @Deenuji 12@ManishSolanki 19 @Anil_g 10 @NathanAlvares24 17 @VishnuReddy1997 6 @Expiscornovus 10 @Tjan 5 @Nived_Nambiar 10 @eetuRobo 3 @SudeepGhatakNZ 8 Week 3 Results: Congratulations to the Week 3 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Week 3:Community MembersSolutionsSuper UsersSolutionsPower Automate Deenuji32ManishSolanki55VishnuReddy199724NathanAlvares2444Anil_g22SudeepGhatakNZ40eetuRobo18Nived_Nambiar28Tjan8David_MA22 Week 4 Results: Congratulations to the Week 4 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Week 4:Community MembersSolutionsSuper UsersSolutionsPower Automate Deenuji11FLMike31Sayan11ManishSolanki16VishnuReddy199710creativeopinion14Akshansh-Sharma3SudeepGhatakNZ7claudiovc2CFernandes5 misc2Nived_Nambiar5 Usernametwice232rzaneti5 eetuRobo2 Anil_g2 SharonS2
On July 16, 2024, we published the 2024 release wave 2 plans for Microsoft Dynamics 365 and Microsoft Power Platform. These plans are a compilation of the new capabilities planned to be released between October 2024 to March 2025. This release introduces a wealth of new features designed to enhance customer understanding and improve overall user experience, showcasing our dedication to driving digital transformation for our customers and partners. The upcoming wave is centered around utilizing advanced AI and Microsoft Copilot technologies to enhance user productivity and streamline operations across diverse business applications. These enhancements include intelligent automation, AI-powered insights, and immersive user experiences that are designed to break down barriers between data, insights, and individuals. Watch a summary of the release highlights. Discover the latest features that empower organizations to operate more efficiently and adaptively. From AI-driven sales insights and customer service enhancements to predictive analytics in supply chain management and autonomous financial processes, the new capabilities enable businesses to proactively address challenges and capitalize on opportunities.
We're embarking on a journey to enhance your experience by transitioning to a new community platform. Our team has been diligently working to create a fresh community site, leveraging the very Dynamics 365 and Power Platform tools our community advocates for. We started this journey with transitioning Copilot Studio forums and blogs in June. The move marks the beginning of a new chapter, and we're eager for you to be a part of it. The rest of the Power Platform product sites will be moving over this summer. Stay tuned for more updates as we get closer to the launch. We can't wait to welcome you to our new community space, designed with you in mind. Let's connect, learn, and grow together. Here's to new beginnings and endless possibilities! If you have any questions, observations or concerns throughout this process please go to https://aka.ms/PPCommSupport. To stay up to date on the latest details of this migration and other important Community updates subscribe to our News and Announcements forums: Copilot Studio, Power Apps, Power Automate, Power Pages