├── CHANGELOG.md
├── CODE_OF_CONDUCT.md
├── FAQ.md
├── LICENSE
├── README.md
├── SECURITY.md
├── SUPPORT.md
├── documentation
├── import-from-grid.md
└── module-import.md
└── examples
├── DESCRIBE.md
├── EXPLODE.md
├── IF_TYPE.md
├── Lib.md
├── REVERSETEXT.md
└── excel-json.ts
/CHANGELOG.md:
--------------------------------------------------------------------------------
1 | # CHANGELOG
2 |
3 | ## AFE 1.1 (November 2022)
4 |
5 | ### What's new
6 | Grid tab. You can now view and edit the selected cell using the AFE editor.
7 |
8 | Named function editor. Define and edit named functions using a new friendly interface.
9 |
10 | Name descriptions are now synchronised with Excel’s name manager. When defining names within modules, leading doc comments of the form {"/** */"}
will be saved to the name manager.
11 |
12 | Initial support for locales with different argument separators. AFE still requires that formulas are written using comma (`,`), but now AFE will automatically convert between (`,`) and (`;`) when interacting with the workbook.
13 |
14 | For locales with different function names, you can use Settings to choose between editing formulas in AFE using the same language as Excel, or English.
15 |
16 | Extract formulas from the grid using the "Add function from grid" button. A calculation split into steps across several cells can be pulled out into a reusable `LAMBDA` function with parameters.
17 |
18 | Support for table references, with autocomplete for table and column names.
19 |
20 | Formula formatting (pretty printing) now works for all formulas and will preserve comments.
21 |
22 | Enhanced syntax coloring
23 |
24 | New keybindings for synchronising (Ctrl-S) and formatting formulas (Ctrl-Shift-F)
25 |
26 | ### What's changed
27 | Namespaces have changed to modules. A module is like a namespace, but now the code is managed exclusively by the code editor under the Modules tab. Modules are treated as additional files that travel with the workbook, and the names are synchronised one-way into the Name Manager by AFE.
28 |
29 | The Manager tab has been changed to the Names tab. The Names tab displays the names defined in Excel's name manager, and are two-way synchronised. Names that were exported to the name manager by modules are not displayed.
30 |
31 | The Editor tab has been changed to the Modules tab.
32 |
33 | AFE no longer uses hidden sheets to store formulas. Module files are now stored directly within the workbook. Any existing hidden code sheets in your workbook (from AFE v1.0) are automatically converted to modules. AFE will not delete the hidden sheet automatically.
34 |
35 | ## AFE 1.0 (February 2022)
36 |
37 | ### First release of AFE
38 | Drawing inspiration from popular code editors—including Visual Studio Code—the advanced formula environment add-in provides you with features such as intellisense, code folding, inline error detection, formatting, and namespaces.
39 |
40 | Capabilities in the first release included:
41 | - Enhanced formula editor allows you to add comments to your code, undo and redo your edits, define named formulas, and easily create multi-line formulas
42 | - Share your work with others through GitHub Gists to reap the benefits of repositories and more easily migrate your logic between spreadsheets
43 | - Filter and find your formulas with intelligent filter functionality to easily locate the formula you need
44 |
--------------------------------------------------------------------------------
/CODE_OF_CONDUCT.md:
--------------------------------------------------------------------------------
1 | # Microsoft Open Source Code of Conduct
2 |
3 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/).
4 |
5 | Resources:
6 |
7 | - [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/)
8 | - [Microsoft Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/)
9 | - Contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with questions or concerns
10 |
--------------------------------------------------------------------------------
/FAQ.md:
--------------------------------------------------------------------------------
1 | # Frequently asked questions and problems
2 |
3 | #### What is the very-hidden sheet used for?
4 | AFE uses the sheet to detect certain formula locale properties that cannot be extracted from the Office JavaScript API. You can safely delete the sheet at anytime. AFE will recreate the sheet as required when opened. Previous versions of AFE used a hidden sheet to store formulas, this is now deprecated.
5 |
6 | #### I see a "The argument is invalid or missing or has an incorrect format" error when trying to save.
7 | This happens when AFE tries to save a formula with certain errors in, such as a missing bracket. To resolve this issue we first recommend the follow steps:
8 | - Check that none of the formulas have errors (red underlines).
9 | - If the formulas use structured references, check that they match the tables and table columns in the workbook.
10 | - If the error persists, feel free to create an issue on the tracker with the formulas.
11 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | MIT License
2 |
3 | Copyright (c) Microsoft Corporation.
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE
22 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Advanced formula environment, a Microsoft Garage project
2 |
3 | Create and edit formulas using a powerful formula editor. With the advanced formula environment you can:
4 | - View, format, and edit formulas defined in the grid with an advanced formula bar.
5 | - Define and edit named functions, ranges, and formulas that can be synchronised with the Name Manager.
6 | - Create collections of named functions called modules that are defined as code and stored as part of the Workbook.
7 | - Quickly import LAMBDA modules directly from GitHub gists.
8 |
9 | The advanced formula environment (AFE) works in Excel for Desktop, Web, and Mac, without installing any additional software. All you need to do to get started is get the add-in from the Office store: https://aka.ms/get-afe. Once installed, you can find AFE under the Formulas tab in Excel.
10 |
11 | The Microsoft Garage is an outlet for experimental projects for you to try. Learn more at https://garage.microsoft.com.
12 |
13 | #### Localisation
14 | AFE supports formula localisation, including argument separators such as `,` and `;`, and function names. By default, all formulas, including those in modules, will be translated to the workbook's locale. AFE provides a setting to fix all formulas to English.
15 |
16 | #### Content
17 | This repository contains documentation and examples only.
18 |
19 | ## Features
20 |
21 | ### Grid view
22 | The default page is the Grid page, which displays the currently selected cell. AFE will format the formula to fit within the window, and will convert the formula to a single line when commiting back to the workbook. AFE provides a setting to preserve the formula formatting from the cell.
23 |
24 | 
25 |
26 | ### Name manager
27 | The Names tab is a manager for the names defined in the workbook. AFE categorises names as functions, ranges, or formulas. The modules tab is used to track collections of named formulas defined using additional code files.
28 |
29 | 
30 |
31 | ### Named function editor
32 | Define named functions using a friendly editor. No need to write `LAMBDA`. Provide the arguments and the function definition to create a reusable formula.
33 |
34 | 
35 |
36 | ### Modules
37 | Organise collections of named formulas as modules. Modules are defined using files that are stored with the workbook and then loaded into the Name Manager by AFE. Quickly share and import modules from GitHub gists. (Note: modules were previously called namespaces. We changed the name because modules are now exclusively authored as code files and stored within the structure of the document.)
38 |
39 | 
40 |
41 |
42 | ## Contributing
43 |
44 | This project welcomes contributions and suggestions. Most contributions require you to agree to a
45 | Contributor License Agreement (CLA) declaring that you have the right to, and actually do, grant us
46 | the rights to use your contribution. For details, visit https://cla.opensource.microsoft.com.
47 |
48 | When you submit a pull request, a CLA bot will automatically determine whether you need to provide
49 | a CLA and decorate the PR appropriately (e.g., status check, comment). Simply follow the instructions
50 | provided by the bot. You will only need to do this once across all repos using our CLA.
51 |
52 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/).
53 | For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or
54 | contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments.
55 |
56 | ## Trademarks
57 |
58 | This project may contain trademarks or logos for projects, products, or services. Authorized use of Microsoft
59 | trademarks or logos is subject to and must follow
60 | [Microsoft's Trademark & Brand Guidelines](https://www.microsoft.com/en-us/legal/intellectualproperty/trademarks/usage/general).
61 | Use of Microsoft trademarks or logos in modified versions of this project must not cause confusion or imply Microsoft sponsorship.
62 | Any use of third-party trademarks or logos are subject to those third-party's policies.
63 |
--------------------------------------------------------------------------------
/SECURITY.md:
--------------------------------------------------------------------------------
1 |
2 |
3 | ## Security
4 |
5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/Microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/).
6 |
7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets [Microsoft's definition of a security vulnerability](https://docs.microsoft.com/en-us/previous-versions/tn-archive/cc751383(v=technet.10)), please report it to us as described below.
8 |
9 | ## Reporting Security Issues
10 |
11 | **Please do not report security vulnerabilities through public GitHub issues.**
12 |
13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://msrc.microsoft.com/create-report).
14 |
15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the [Microsoft Security Response Center PGP Key page](https://www.microsoft.com/en-us/msrc/pgp-key-msrc).
16 |
17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://www.microsoft.com/msrc).
18 |
19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue:
20 |
21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.)
22 | * Full paths of source file(s) related to the manifestation of the issue
23 | * The location of the affected source code (tag/branch/commit or direct URL)
24 | * Any special configuration required to reproduce the issue
25 | * Step-by-step instructions to reproduce the issue
26 | * Proof-of-concept or exploit code (if possible)
27 | * Impact of the issue, including how an attacker might exploit the issue
28 |
29 | This information will help us triage your report more quickly.
30 |
31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://microsoft.com/msrc/bounty) page for more details about our active programs.
32 |
33 | ## Preferred Languages
34 |
35 | We prefer all communications to be in English.
36 |
37 | ## Policy
38 |
39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://www.microsoft.com/en-us/msrc/cvd).
40 |
41 |
--------------------------------------------------------------------------------
/SUPPORT.md:
--------------------------------------------------------------------------------
1 | # Support
2 |
3 | ## How to file issues and get help
4 |
5 | This project uses GitHub Issues to track bugs and feature requests. Please search the existing
6 | issues before filing new issues to avoid duplicates. For new issues, file your bug or
7 | feature request as a new Issue.
8 |
9 | For help and questions about using this project, please create a new Issue here, or use the [Microsoft Excel Community](https://techcommunity.microsoft.com/t5/microsoft-excel/ct-p/Excel_Cat) and tag using _Advanced formula environment_.
10 |
11 | ## Microsoft Support Policy
12 |
13 | Support for this project is limited to the resources listed above.
14 |
--------------------------------------------------------------------------------
/documentation/import-from-grid.md:
--------------------------------------------------------------------------------
1 | # Import from grid
2 |
3 | The _import from grid_ action is a new **experimental** feature of AFE that allows formulas defined in the grid to be converted to named functions.
4 |
5 | Define the calculation then select the region of cells to include in the funtion, the input cells, and the output cell. AFE will then convert this to a named function.
6 |
7 | 
8 |
9 | AFE tries to automatically detect input and output cells, as well as trying to infer parameter names.
10 |
11 | ### Limitations
12 |
13 | This is an experimental fetaure with known limitations, including lack of support for dynamic arrays. All feedback is appreciated.
14 |
--------------------------------------------------------------------------------
/documentation/module-import.md:
--------------------------------------------------------------------------------
1 | # Module import
2 | AFE allows the import of modules (files that contain named formulas) into a workbook. Currently, AFE only supports importing a module from a GitHub gist URL such as https://gist.github.com/jack-williams/75f6ea2e9745cc31f1733450977db86c.
3 |
4 | # How to import
5 | To import from AFE you need to use the following icon and provide the URL.
6 | 
7 |
8 | When importing from the Names tab, a name for the module that will contain the formulas must be provided. Formulas defined in a module will start with the module name when used from Excel. For example, when importing a module with the content:
9 | ```
10 | formula_a = LAMBDA(x, x + 1);
11 |
12 | formula_b = 10;
13 | ```
14 | into a module named `Module`, you must write `Module.formula_a` to access the function from a cell.
15 |
16 | When importing from the "Modules" tab the module name is optional. If the module name is omitted, the formulas will be appended to the currently open module.
17 |
18 | # Creating gists
19 | To create a gist that holds a module the github website must be used. We do not currently support creating gists from AFE. If you are signed into github you can visit https://gist.github.com/ to create a new gist. The name of the gist can be anything, AFE does not use this currently. AFE assumes that the gist contains a single file.
20 | Gists can be public or secret. _Secret gists can be accessed by anyone that has the URL._ AFE works with both public and secret gists.
21 | 
22 |
23 |
24 | # Module files
25 | Currently, AFE does not allow modules to contain tab `\t` or carriage return `\r` characters. For indenting and line breaks, spaces and newline `\n` must be used, respectively.
26 |
--------------------------------------------------------------------------------
/examples/DESCRIBE.md:
--------------------------------------------------------------------------------
1 | ### Description
2 | Describes a dataset using summary statistics. When `features` is omitted then `DESCRIBE` uses every aggregation function.
3 | - `array` an array to summarise by column.
4 | - `[features]` a string or 1-D array (column or row major) of aggregation functions names
5 |
6 | ### Code
7 | ```
8 | DESCRIBE = LAMBDA(array, [features],
9 | LET(
10 | _sum, LAMBDA(x, SUM(x)),
11 | _mean, LAMBDA(x, AVERAGE(x)),
12 | _count, LAMBDA(x, COUNT(x)),
13 | _std, LAMBDA(x, STDEV(x)),
14 | _min, LAMBDA(x, MIN(x)),
15 | _25, LAMBDA(x, PERCENTILE.INC(x, 0.25)),
16 | _50, LAMBDA(x, PERCENTILE.INC(x, 0.5)),
17 | _75, LAMBDA(x, PERCENTILE.INC(x, 0.75)),
18 | _max, LAMBDA(x, MAX(x)),
19 | knownFunctions, {"SUM"; "MEAN"; "COUNT"; "STD"; "MIN"; "25%"; "50%"; "75%"; "MAX"},
20 | getAggregation, LAMBDA(id, array,
21 | CHOOSE(id, _sum, _mean, _count, _std, _min, _25, _50, _75, _max)(array)
22 | ),
23 | featureVector, IF(
24 | ISOMITTED(features),
25 | knownFunctions,
26 | IF(ROWS(features) = 1, TRANSPOSE(features), features)
27 | ),
28 | unknownFunctions, FILTER(featureVector, ISERROR(XMATCH(featureVector, knownFunctions, 0))),
29 | IF(
30 | TYPE(unknownFunctions) = 64,
31 | "Unknown functions " & ARRAYTOTEXT(unknownFunctions),
32 | MAKEARRAY(
33 | ROWS(featureVector),
34 | COLUMNS(array) + 1,
35 | LAMBDA(i, j,
36 | LET(
37 | functionName, INDEX(featureVector, i, 1),
38 | functionId, XMATCH(functionName, knownFunctions, 0),
39 | IF(j = 1, functionName, getAggregation(functionId, INDEX(array, 0, j - 1)))
40 | )
41 | )
42 | )
43 | )
44 | )
45 | );
46 | ```
47 |
--------------------------------------------------------------------------------
/examples/EXPLODE.md:
--------------------------------------------------------------------------------
1 | ### Description
2 | Explodes a text into a single-row array of single character texts.
3 |
4 |
5 | ### Code
6 | ```
7 | explode =
8 | LAMBDA(text,
9 | IF(LEN(text)=0,
10 | #NULL!, // Excel does not support empty arrays so we return the #NULL! error
11 | MAKEARRAY(1,LEN(text),lambda(i,j, MID(text,j,1)))));
12 |
13 | test1 = explode("foo");
14 | test2 = explode("");
15 | ```
16 |
--------------------------------------------------------------------------------
/examples/IF_TYPE.md:
--------------------------------------------------------------------------------
1 | ### Description
2 | IF variants for different types.
3 |
4 |
5 | ### Code
6 | ```
7 | IFBLANK = LAMBDA(value, value_if_blank,
8 | IF(ISBLANK(value), value_if_blank, value)
9 | );
10 |
11 | IFNUMBER = LAMBDA(value, value_if_num,
12 | IF(ISNUMBER(value), value_if_num, value)
13 | );
14 |
15 | IFTEXT = LAMBDA(value, value_if_text,
16 | IF(ISTEXT(value), value_if_text, value)
17 | );
18 |
19 | IFLOGICAL = LAMBDA(value, value_if_logical,
20 | IF(ISLOGICAL(value), value_if_logical, value)
21 | );
22 | ```
23 |
24 | ### Gist link
25 | https://gist.github.com/jack-williams/5859d170fcb363dad1620c4d40770527
26 |
--------------------------------------------------------------------------------
/examples/Lib.md:
--------------------------------------------------------------------------------
1 | ### Description
2 | A collection of basic functions on arrays and texts.
3 |
4 | ### Code
5 | ```
6 | // Lib - a library of basic operations on Excel types
7 |
8 | // ======================================================================================================
9 | // Testing infrastructure
10 | // To test everything, put =DoIt into cell A1 (or any cell)
11 |
12 | test_text =
13 | textjoin("|", TRUE
14 | , totext_test
15 | , test_nfib
16 | , test_stack_depth
17 | , test_textsplit
18 | , test_vstack
19 | , test_pair
20 | , test_1_vconcat
21 | , test_2_vconcat
22 | );
23 |
24 | DoIt =
25 | let( ms_value, timer(LAMBDA(test_text))
26 | , ms, fst(ms_value)
27 | , results, snd(ms_value)
28 | , results_text, index(results,1,1) // coerce from [1x1] array sometimes returned by textjoin
29 | , header, "Total DoIt time " & ms & "ms||"
30 | , transpose(textsplit(header & results_text,"|"))
31 | );
32 |
33 | // ======================================================================================================
34 | // go is a test runner for writing tests.
35 |
36 | go = LAMBDA(thunk,expected,
37 | let(ms_value, timer(thunk)
38 | , ms, fst(ms_value)
39 | , value, snd(ms_value)
40 | , ms & "ms " &
41 | IF( totext(value)=totext(expected)
42 | , "Pass got "&totext(value)&" as expected"
43 | , "Fail got "&totext(value)&" but expected "&totext(expected)
44 | )
45 | )
46 | );
47 |
48 | // ======================================================================================================
49 | // Excel type codes and the totext function, to turn any type into a text
50 |
51 | // Excel TYPE codes
52 | TYPE_Number = 1;
53 | TYPE_Text = 2;
54 | TYPE_Logical = 4;
55 | TYPE_Error = 16;
56 | TYPE_Array = 64;
57 |
58 | is_text = lambda(value, type(value)=TYPE_Text);
59 | is_error = lambda(value, type(value)=TYPE_Error);
60 |
61 | // typeof
62 | typeof = lambda(value,
63 | switch( type(value)
64 | , TYPE_Number, "number"
65 | , TYPE_Text, "text"
66 | , TYPE_Logical, "logical"
67 | , TYPE_Error, "error"
68 | , TYPE_Array, "["& rows(value) &"x" & columns(value) &"]"
69 | )
70 | );
71 |
72 | // turn any value, array or not, into a single string
73 | totext = lambda(value,
74 | IF( TYPE(value)=TYPE_Array
75 | , arraytotext(value,1)
76 | , valuetotext(value,1)
77 | ));
78 |
79 | // show different types of literals
80 | totext_test =
81 | textjoin(" ", TRUE
82 | , totext( TRUE )
83 | , totext( pi() )
84 | , totext( 42 )
85 | , totext( 01/01/2021 )
86 | , totext( "Menen" )
87 | , totext( "12345678" )
88 | , totext( #VALUE! )
89 | , totext( {1,2,3} )
90 | , totext( TRANSPOSE({1,2,3}) )
91 | , totext( LAMBDA(x,x) )
92 | );
93 |
94 | // ======================================================================================================
95 | // Timing a computation wrapped in a thunk
96 |
97 | timer = LAMBDA(thunk,
98 | LET( time_0, NOW()
99 | , value, thunk()
100 | , time_1, NOW()
101 | , days, time_1 - time_0
102 | , ms, days * 24 * 60 * 60 * 1000 // milliseconds (resolution 10ms on desktop)
103 | , pair(round(ms,0),value)
104 | )
105 | );
106 |
107 | // ======================================================================================================
108 | // Simple examples of recursion
109 |
110 | // nfib benchmark (nfib(30) takes about 2s on desktop). Careful, no interrupt.
111 | nfib = LAMBDA(n,
112 | if(n<2, 1, 1 + nfib(n-1) + nfib(n-2))
113 | );
114 | test_nfib = go(lambda( nfib(22) ), 57313);
115 |
116 | mytest = go(LAMBDA( nfib(22 )), 57313);
117 |
118 | // stack depth - test how deep we can go
119 | // when stack depth exceeded, we get the #NUM! error
120 | // for example, stack_depth(342)=#NUM!
121 | stackdepth = LAMBDA(depth,
122 | IF(depth<=1, 1, 1+stackdepth(depth-1))
123 | );
124 | d=5300; // 5300 works
125 | test_stack_depth = go( lambda(stackdepth(d)), d );
126 |
127 | // ======================================================================================================
128 | // Function to split a text into words separated by the delimiter symbol
129 |
130 | textsplit = lambda(arg,delimiter,
131 | let( step_1, explode(delimiter & arg & delimiter)
132 | , step_2, makearray(1,columns(step_1),lambda(i,j,
133 | IF(INDEX(step_1,1,j)=delimiter,j,0) ))
134 | , starts, filter(step_2, step_2>0)
135 | , step_4, makearray(1,columns(starts)-1,lambda(i,j,
136 | let( start, index(starts,1,j)
137 | , count, index(starts,1,j+1)-start-1
138 | , MID(arg,start,count)
139 | )))
140 | , step_4
141 | )
142 | );
143 | explode = LAMBDA(string, makearray(1,LEN(string),lambda(i,j, MID(string,j,1))));
144 |
145 | test_textsplit =
146 | go( lambda(textsplit("one,,two,three",","))
147 | , {"one", "", "two", "three"}
148 | );
149 |
150 | // ======================================================================================================
151 | // Vectors: functions to make row and column vectors
152 |
153 | r_vector =
154 | lambda([x_1],[x_2],[x_3],[x_4],[x_5],[x_6],[x_7],[x_8],[x_9],[x_10],
155 | let(w, ifs(isomitted(x_1),0,
156 | isomitted(x_2),1,
157 | isomitted(x_3),2,
158 | isomitted(x_4),3,
159 | isomitted(x_5),4,
160 | isomitted(x_6),5,
161 | isomitted(x_7),6,
162 | isomitted(x_8),7,
163 | isomitted(x_9),8,
164 | isomitted(x_10),9,
165 | true,10),
166 | array,makearray(1,w,lambda(i,j,switch(j,1,x_1,2,x_2,3,x_3,4,x_4,5,x_5,6,x_6,7,x_7,8,x_8,9,x_9,10,x_10))),
167 | if(w=0,#null!,array)
168 | ));
169 |
170 | c_vector =
171 | lambda([x_1],[x_2],[x_3],[x_4],[x_5],[x_6],[x_7],[x_8],[x_9],[x_10],
172 | let(row, r_vector(x_1,x_2,x_3,x_4,x_5,x_6,x_7,x_8,x_9,x_10),
173 | col, if(type(row)=64,transpose(row),row),
174 | col
175 | ));
176 |
177 | // ======================================================================================================
178 | // zip two column vectors of same height into a two-column table
179 |
180 | c_zip = lambda(c_1,c_2, makearray(rows(c_1), 2, lambda(i,j,index(if(j=1,c_1,c_2),i,1))));
181 |
182 | // ======================================================================================================
183 | // vstack(array_1,array_2) returns the array obtained by stacking array_1 and array_2 vertically.
184 |
185 | vstack =
186 | LAMBDA(array_1,array_2,
187 | LET(rows_1, ROWS(array_1),
188 | rows_2, ROWS(array_2),
189 | cols_1, COLUMNS(array_1),
190 | cols_2, COLUMNS(array_2),
191 | blank, "",
192 | makearray(rows_1+rows_2, MAX(cols_1,cols_2), lambda(i,j,
193 | IF(i<=rows_1,
194 | IF(j<=cols_1,INDEX(array_1,i,j),blank),
195 | IF(j<=cols_2,INDEX(array_2,i-rows_1,j),blank)) ))
196 | ));
197 |
198 | test_vstack =
199 | go( lambda(Lib.VSTACK(SEQUENCE(3,4), SEQUENCE(4,5)))
200 | , {1,2,3,4,"";5,6,7,8,"";9,10,11,12,"";1,2,3,4,5;6,7,8,9,10;11,12,13,14,15;16,17,18,19,20}
201 | );
202 |
203 | // hstack(array_1,array_2) returns the array obtained by stacking array_1 and array_2 horizontally.
204 | hstack =
205 | LAMBDA(array_1,array_2,
206 | LET(rows_1, ROWS(array_1),
207 | rows_2, ROWS(array_2),
208 | cols_1, COLUMNS(array_1),
209 | cols_2, COLUMNS(array_2),
210 | blank, " ",
211 | makearray(MAX(rows_1,rows_2), cols_1+cols_2, lambda(i,j,
212 | IF(j<=cols_1,
213 | IF(i<=rows_1,INDEX(array_1,i,j),blank),
214 | IF(i<=rows_2,INDEX(array_2,i,j-cols_1),blank)) ))
215 | ));
216 |
217 | // ======================================================================================================
218 | // Array concatenation: v_concat { thunk1; ... thunkN } where each thunki=lambda(arrayi)
219 | // computes the vertical stack of array1,...,arrayN, with blank padding to the right.
220 |
221 | test_1_vconcat =
222 | LET(sample_input, c_vector(lambda({1,10;2,20;3,30}), lambda({"four";5}), lambda({1,2,3})),
223 | go( lambda(vconcat(sample_input)), {1,10,"";2,20,"";3,30,"";"four","","";5,"","";1,2,3} ));
224 |
225 | test_2_vconcat =
226 | let(sample_input, c_vector(lambda({1,10;2,20;3,30})),
227 | go( lambda(vconcat(sample_input)), {1,10;2,20;3,30} ));
228 |
229 | seq_or = lambda(b_1,b_2,if(b_1,true,b_2));
230 |
231 | vconcat = lambda(c_array_thunks,
232 | let(c_row_counts, map(c_array_thunks, lambda(thunk, rows(thunk()))),
233 | total_rows, sum(c_row_counts),
234 | max_columns, reduce(1,c_array_thunks,lambda(acc,thunk,max(acc,columns(thunk())))),
235 | // coord(i) = pair(i_thunk,row_within_thunk)
236 | coord_0, num_pair(0,0),
237 | scanner, lambda(p,_,
238 | let(i_thunk, num_fst(p),
239 | row_within_thunk, num_snd(p),
240 | // if we need to increment i_thunk?
241 | if( seq_or(i_thunk=0, // first call, or
242 | row_within_thunk=index(c_row_counts,i_thunk,1)), // at end of the previous thunk
243 | //then
244 | num_pair(i_thunk+1,1),
245 | //else
246 | num_pair(i_thunk,row_within_thunk+1)
247 | )
248 | )),
249 | coords, scan(coord_0, sequence(total_rows), scanner),
250 | maker, lambda(i,j,
251 | let(p, index(coords,i,1),
252 | i_thunk, num_fst(p),
253 | row_within_thunk, num_snd(p),
254 | array, index(c_array_thunks,i_thunk,1)(),
255 | item, if(j<=columns(array),index(array,row_within_thunk,j),""),
256 | item)),
257 | result, makearray(total_rows,max_columns,maker),
258 | result
259 | ));
260 |
261 | // ======================================================================================================
262 | // Flatten 2D matrix into row or column vector.
263 |
264 | flatten_to_row =
265 | LAMBDA(array,
266 | LET(rows, ROWS(array),
267 | cols, COLUMNS(array),
268 | array, makearray(1,rows*cols,lambda(i,j, index(array,floor.math((j-1)/cols)+1,mod(j-1,cols)+1) )),
269 | array
270 | ));
271 |
272 | flatten_to_column =
273 | LAMBDA(array,
274 | LET(rows, ROWS(array),
275 | cols, COLUMNS(array),
276 | array, makearray(rows*cols,1,lambda(i,j, index(array,floor.math((i-1)/cols)+1,mod(i-1,cols)+1) )),
277 | array
278 | ));
279 |
280 | // ======================================================================================================
281 | // Pairs: encoded with LAMBDA, so we can store arbitrary values including arrays
282 | // We can store these in arrays, because we can store LAMBDA in arrays, but not in cells.
283 |
284 | pair = LAMBDA(x_1,x_2, LAMBDA(j,switch(j,1,x_1,2,x_2)));
285 | fst = LAMBDA(p, p(1));
286 | snd = LAMBDA(p, p(2));
287 | test_pair = go( lambda(snd(pair( {1,2}, {3,4} ))), {3,4} );
288 |
289 | // ======================================================================================================
290 | // Pairs: number pairs encoded as a text. Faster than LAMBDA encoded pairs.
291 |
292 | num_pair = LAMBDA(x_1,x_2, x_1&":"&x_2);
293 | num_fst = LAMBDA(p, let(colon,find(":",p), x_1,left(p,colon-1), numbervalue(x_1)));
294 | num_snd = LAMBDA(p, let(colon,find(":",p), x_2,right(p,len(p)-colon), numbervalue(x_2)));
295 |
296 | // ======================================================================================================
297 | // set of strings represented as #NULL! (if the set is empty), or a row vector (if set is non-empty)
298 | // Remember that a single string looks and behaves like a 1x1 array
299 |
300 | empty_set = #NULL!;
301 | is_empty_set = is_error;
302 | union = lambda(set_1, set_2,
303 | if(is_empty_set(set_1), set_2,
304 | if(is_empty_set(set_2), set_1,
305 | unique(Lib.hstack(set_1,set_2),TRUE))));
306 | set_from_spaced_string = lambda(string, IF(string="",empty_set,Lib.textsplit(string," ")));
307 | spaced_string_from_set = lambda(set, TEXTJOIN(" ",TRUE,set));
308 | member = LAMBDA(quarry,set,IF(is_empty_set(set),FALSE,REDUCE(FALSE,set,lambda(acc,item,OR(acc,item=quarry)))));
309 | ```
310 |
--------------------------------------------------------------------------------
/examples/REVERSETEXT.md:
--------------------------------------------------------------------------------
1 | ### Description
2 | Reverses a string.
3 |
4 |
5 | ### Code
6 | ```
7 | REVERSETEXT = LAMBDA(text, CONCAT(LEFT(RIGHT(text, SEQUENCE(LEN(text))), 1)));
8 | ```
9 |
10 | ### Gist link
11 | https://gist.github.com/jack-williams/6bb94977ddb0472c9f443f98bff4d59e
12 |
--------------------------------------------------------------------------------
/examples/excel-json.ts:
--------------------------------------------------------------------------------
1 | // json-excel.ts
2 | // Load this code file using ScriptLab to make JSON functionality available as custom functions in Excel
3 | // Documentation: https://docs.microsoft.com/en-us/office/dev/add-ins/excel/excel-data-types-overview
4 |
5 | /**
6 | * GET JSON from URL.
7 | * @customfunction
8 | * @param {string} url
9 | * @returns {any} Results of the query.
10 | */
11 | async function get_json(url) {
12 | const options = {
13 | method: "GET"
14 | };
15 |
16 | //console.log(url);
17 | //console.log(options);
18 |
19 | try {
20 | const response = await fetch(url, options);
21 | if (!response.ok) {
22 | throw new Error(`Error! status: ${response.status}`);
23 | }
24 |
25 | const result = await response.json();
26 | return value_to_excel(result);
27 | } catch (err) {
28 | console.log(err);
29 | return value_to_excel("caught: " + err.message);
30 | }
31 | }
32 |
33 | /**
34 | * GET JSON lines from URL.
35 | * @customfunction
36 | * @param {string} url
37 | * @returns {any} Results of the query.
38 | */
39 | async function get_json_lines(url) {
40 | const options = {
41 | method: "GET"
42 | };
43 |
44 | //console.log(url);
45 | //console.log(options);
46 |
47 | try {
48 | const response = await fetch(url, options);
49 | if (!response.ok) {
50 | throw new Error(`Error! status: ${response.status}`);
51 | }
52 |
53 | const text = await response.text();
54 | const jsons = await text.split("\n");
55 | var N = jsons.length-1; // last entry will be an empty string following last "\n"
56 | var array = new Array(N);
57 | for (var i = 0; i < N; i++) {
58 | const json = jsons[i];
59 | try {
60 | array[i] = JSON.parse(jsons[i]);
61 | }
62 | catch(err) {
63 | array[i] = "error parsing: "+json+"length "+json.length;
64 | //console.log(array[i]);
65 | }
66 | }
67 | const excel = value_to_excel({"lines":array});
68 | //console.log(array);
69 | return excel;
70 | } catch (err) {
71 | console.log(err);
72 | return value_to_excel("caught: " + err.message);
73 | }
74 | }
75 |
76 | /**
77 | * POST JSON to URL.
78 | * @customfunction
79 | * @param {string} url
80 | * @param {any} json_data
81 | * @returns {any} Results of the query.
82 | */
83 | async function post_json(url, json_data) {
84 | const options = {
85 | method: "POST",
86 | headers: {
87 | "Content-Type": "application/json"
88 | },
89 | body: json_data
90 | };
91 |
92 | //console.log(options);
93 |
94 | try {
95 | const response = await fetch(url, options);
96 | if (!response.ok) {
97 | throw new Error(`Error! status: ${response.status}`);
98 | }
99 |
100 | const result = await response.json();
101 | return value_to_excel(result);
102 | } catch (err) {
103 | console.log(err);
104 | return value_to_excel("caught: " + err.message);
105 | }
106 | }
107 |
108 | /**
109 | * Encode part of URI
110 | * @customfunction
111 | * @param {string} text
112 | * @returns {string} URI encoded text
113 | */
114 | function encodeURI(text: string) {
115 | return encodeURIComponent(text);
116 | }
117 |
118 | /**
119 | * Constructs a Yellow entity
120 | * @customfunction
121 | * @param {string} json
122 | * @returns {any} Yellow value
123 | */
124 | function parse_JSON(json: string) {
125 | const obj = JSON.parse(json);
126 | return value_to_excel(obj);
127 | }
128 |
129 | const nullErrorValue = {
130 | type: "Error",
131 | basicType: "Error",
132 | basicValue: "#NULL!"
133 | };
134 |
135 | function value_to_excel(value) {
136 | // recall that typeof null == "object"
137 | if (value == null) return nullErrorValue;
138 | switch (typeof value) {
139 | case "boolean":
140 | return {
141 | type: "Boolean",
142 | basicValue: value
143 | };
144 |
145 | case "string":
146 | return {
147 | type: "String",
148 | basicValue: value
149 | };
150 |
151 | case "number":
152 | return {
153 | type: "Double",
154 | basicValue: value
155 | };
156 |
157 | case "object":
158 | if (value.constructor === Array) {
159 | const length = value.length;
160 | if (length == 0) return nullErrorValue; // Excel has no empty arrays
161 |
162 | var rows = new Array(length);
163 | for (var i = 0; i < length; i++) rows[i] = [value_to_non_array_excel(value[i])];
164 | return {
165 | type: "Array",
166 | elements: rows
167 | };
168 | }
169 |
170 | const obj = value as Object;
171 | var keys = "";
172 | var outcome: Object = {};
173 | for (var key in obj) {
174 | if (obj.hasOwnProperty(key)) {
175 | var lowerKey = key.toLowerCase();
176 | while(outcome.hasOwnProperty(lowerKey)) // make the lower case key unique, if need be
177 | lowerKey += "9";
178 | if (keys=="")
179 | keys = lowerKey;
180 | else
181 | keys = keys+","+lowerKey;
182 | const value = obj[key];
183 | outcome[lowerKey] = value_to_excel(value);
184 | }
185 | }
186 |
187 | return {
188 | type: "Entity",
189 | text: keys,
190 | properties: outcome
191 | };
192 |
193 | default:
194 | return {
195 | type: "String",
196 | basicValue: "DEFAULT - unexpected"
197 | };
198 | }
199 | }
200 |
201 | // Excel does not support an array nested inside another, so wrap in an entity
202 | function value_to_non_array_excel(value) {
203 | if (value == null) return nullErrorValue;
204 | const excel = value_to_excel(value);
205 | switch (typeof value) {
206 | case "object":
207 | if (value.constructor === Array) {
208 | return {
209 | type: "Entity",
210 | text: "Nested array",
211 | properties: excel
212 | };
213 | }
214 | return excel;
215 |
216 | default:
217 | return excel;
218 | }
219 | }
220 |
221 |
222 |
--------------------------------------------------------------------------------