-
Notifications
You must be signed in to change notification settings - Fork 56
/
Copy pathCode.gs
164 lines (152 loc) · 6.78 KB
/
Code.gs
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
const saveToDriveAsJson = false;
const ss = SpreadsheetApp.getActiveSpreadsheet();
const activeSheet = ss.getActiveSheet();
function getPrecedents() {
const rawCellData = scanCurrentSheet();
let result = {};
rawCellData.forEach(cellData => {
let rawRangesR1C1 = cellData.rangesR1C1;
rawRangesR1C1.forEach(range => {
let enumeratedData = enumerateRange(range, cellData.rowIndex, cellData.columnIndex);
result[enumeratedData.cell] = Object.keys(result).includes(enumeratedData.cell)
? [...new Set(result[enumeratedData.cell].concat(enumeratedData.precedents))]
: enumeratedData.precedents;
});
let rawCellR1C1 = cellData.cellsR1C1;
rawCellR1C1.forEach(cell => {
let cellA1Notation = convertCellsFromR1C1toA1Notation(cell, cellData.rowIndex, cellData.columnIndex);
result[cellA1Notation.cell] = Object.keys(result).includes(cellA1Notation.cell)
? [...new Set(result[cellA1Notation.cell].concat(cellA1Notation.precedents))]
: cellA1Notation.precedents;
});
});
console.log(JSON.stringify(result, null, 2));
saveToDriveAsJson ? DriveApp.createFile(`${ss.getName()} — ${activeSheet.getSheetName()} — graph.json`, JSON.stringify(result, null, 2), MimeType.PLAIN_TEXT) : null;
}
function scanCurrentSheet() {
const formulasR1C1 = activeSheet.getDataRange().getFormulasR1C1();
let result = [];
formulasR1C1.forEach((row, rowIndex) => {
row.forEach((cell, columnIndex) => {
let dict = {};
if (cell) {
dict["formula"] = cell;
dict["rowIndex"] = rowIndex;
dict["columnIndex"] = columnIndex;
let formattedCell = JSON.parse(JSON.stringify(cell))
.replace(/''/gmi, "'")
.replace(/\\/gmi, "\\")
dict["rangesR1C1"] = [];
let rangesRegExPattern = `(?:[R|C]\\[-?\\d+\\]){0,2}:(?:[R|C]\\[-?\\d+\\]){0,2}`;
try {
cell.match(/!?(?:[R|C]\[-?\d+\]){0,2}:(?:[R|C]\[-?\d+\]){0,2}/gmi).filter(data => !data.includes("!") && data !== ":" ? dict["rangesR1C1"].push(data) : null);
} catch (e) { }
try {
cell.match(/\b\w+!(?:[R|C]\[-?\d+\]){0,2}:(?:[R|C]\[-?\d+\]){0,2}/gmi).forEach(data => dict["rangesR1C1"].push(data));
} catch (e) { }
try {
let moreRangeReferences = getMatchingRangeCellRef(formattedCell, rangesRegExPattern);
moreRangeReferences.length > 0 ? moreRangeReferences.forEach(data => dict["rangesR1C1"].push(JSON.parse(JSON.stringify(data)))) : null;
} catch (e) { }
dict["cellsR1C1"] = [];
let cellsRegExPattern = `(?<!:)R\\[\\-?\\d+\\]C\\[\\-?\\d+\\](?!:)`;
try {
cell.match(/!?(?<!:)R\[\-?\d+\]C\[\-?\d+\](?!:)/gmi).filter(data => !data.includes("!") ? dict["cellsR1C1"].push(data) : null);
} catch (e) { }
try {
cell.match(/\b\w+!(?<!:)R\[\-?\d+\]C\[\-?\d+\](?!:)/gmi).forEach(data => dict["cellsR1C1"].push(data));
} catch (e) { }
try {
let moreCellReferences = getMatchingRangeCellRef(formattedCell, cellsRegExPattern);
moreCellReferences.length > 0 ? moreCellReferences.forEach(data => dict["cellsR1C1"].push(JSON.parse(JSON.stringify(data)))) : null;
} catch (e) { }
result.push(dict);
}
});
});
return result;
}
function getMatchingRangeCellRef(cell, regexPattern) {
const sheets = ss.getSheets();
let result = [];
sheets.forEach(sheet => {
let sheetNameFormat = sheet.getSheetName()
.replace(/\\/gmi, "\\\\")
.replace(/\//gmi, "\\\/")
.replace(/\|/gmi, "\\\|")
.replace(/\./gmi, "\\\.")
.replace(/\+/gmi, "\\\+")
.replace(/\*/gmi, "\\\*")
.replace(/\?/gmi, "\\\?")
.replace(/\^/gmi, "\\\^")
.replace(/\$/gmi, "\\\$")
.replace(/\(/gmi, "\\\(")
.replace(/\)/gmi, "\\\)")
.replace(/\[/gmi, "\\\[")
.replace(/\]/gmi, "\\\]")
.replace(/\{/gmi, "\\\{")
.replace(/\}/gmi, "\\\}")
let finalRegExPattern = new RegExp(`'${sheetNameFormat}'!${regexPattern}`, "gmi");
let matchedReferences = cell.match(finalRegExPattern);
matchedReferences?.forEach(data => result.push(data));
});
return result;
}
function enumerateRange(range, rowIndex, columnIndex) {
let enumerated = [];
const lastRow = activeSheet.getLastRow();
const lastColumn = activeSheet.getLastColumn();
const isDifferentSheet = range.includes("!");
const rangeData = isDifferentSheet ? range.split("!") : null;
range = isDifferentSheet ? rangeData[1] : range;
let [startCell, endCell] = range.split(":");
startCell = startCell.includes("R") && startCell.includes("C") ? startCell :
(!startCell.includes("R") ? `R[${0 - rowIndex}]${startCell}` :
(!startCell.includes("C") ? `${startCell}C[${(0 - columnIndex)}]` :
startCell
)
);
endCell = endCell.includes("R") && endCell.includes("C") ? endCell :
(!endCell.includes("R") ? `R[${(lastRow - 1) - rowIndex}]${endCell}` :
(!endCell.includes("C") ? `${endCell}C[${(lastColumn - 1) - columnIndex}]` :
endCell
)
);
const [, startRowIndex, startColumnIndex] = /R\[(-?\d+)\]C\[(-?\d+)\]/gmi.exec(startCell);
const [, endRowIndex, endColumnIndex] = /R\[(-?\d+)\]C\[(-?\d+)\]/gmi.exec(endCell);
const corrected = {
startRowIndex: +startRowIndex + +rowIndex,
startColumnIndex: +startColumnIndex + +columnIndex,
endRowIndex: +endRowIndex + +rowIndex,
endColumnIndex: +endColumnIndex + +columnIndex
}
for (let j = corrected.startColumnIndex; j <= corrected.endColumnIndex; j++) {
for (let i = corrected.startRowIndex; i <= corrected.endRowIndex; i++) {
let a1Notation = activeSheet.getRange(`R[${i}]C[${j}]`).getA1Notation();
enumerated.push(isDifferentSheet ? `${rangeData[0]}!${a1Notation}` : a1Notation);
}
}
const cell = activeSheet.getRange(`R[${rowIndex}]C[${columnIndex}]`).getA1Notation();
return {
cell: cell,
precedents: [...new Set(enumerated)]
};
}
function convertCellsFromR1C1toA1Notation(cellR1C1Reference, rowIndex, columnIndex) {
let enumerated = [];
const isDifferentSheet = cellR1C1Reference.includes("!");
const cellReferenceData = isDifferentSheet ? cellR1C1Reference.split("!") : null;
cellR1C1Reference = isDifferentSheet ? cellReferenceData[1] : cellR1C1Reference;
const [, startRowIndex, startColumnIndex] = /R\[(-?\d+)\]C\[(-?\d+)\]/gmi.exec(cellR1C1Reference);
const corrected = {
startRowIndex: +startRowIndex + +rowIndex,
startColumnIndex: +startColumnIndex + +columnIndex,
}
const a1Notation = ss.getRange(`R[${corrected.startRowIndex}]C[${corrected.startColumnIndex}]`).getA1Notation();
enumerated.push(isDifferentSheet ? `${cellReferenceData[0]}!${a1Notation}` : a1Notation);
const cell = activeSheet.getRange(`R[${rowIndex}]C[${columnIndex}]`).getA1Notation();
return {
cell: cell,
precedents: [...new Set(enumerated)]
};
}