Skip to content

Instantly share code, notes, and snippets.

@lemkorp
Created July 26, 2019 13:08
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save lemkorp/d784081c2d6acdaae7ff76d9a2195053 to your computer and use it in GitHub Desktop.
Save lemkorp/d784081c2d6acdaae7ff76d9a2195053 to your computer and use it in GitHub Desktop.
Create a new snippet from a blank template.
name: Tableaux
description: Create a new snippet from a blank template.
host: EXCEL
api_set: {}
script:
content: |
$("#creation").click(() => tryCatch(creation));
$("#ajout").click(() => tryCatch(ajoutDonnees));
$("#somme").click(() => tryCatch(somme));
$("#ajoutjson").click(() => tryCatch(ajoutJSON));
$("#filtre").click(() => tryCatch(filtre));
$("#stopfiltre").click(() => tryCatch(stopFiltre));
$("#trier").click(() => tryCatch(trier));
$("#seltitres").click(() => tryCatch(selTitres));
$("#seldonnees").click(() => tryCatch(selDonnees));
$("#seltableau").click(() => tryCatch(selTableau));
$("#selcolprix").click(() => tryCatch(selColPrix));
async function creation() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.add("A1:C1", true); // Les données impactées true=>en-tête
t.name = "ventes"; // Nom du tableau
t.getHeaderRowRange().values = [["Formation", "Nombre", "Prix"]]; // En-têtes
t.rows.add(null, [
// Ajout de lignes à la fin du tableau ou index
["Office 2016", 2, 1200],
["Office 2019", 3, 1400],
["Office 2016", 1, 1200],
["Windows 10", 1, 950],
["Office 2019", 3, 1400],
["Windows 10", 9, 950],
["Office 2019", 2, 1400]
]);
});
}
async function ajoutDonnees() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
let nouveau = [["Office 2019", 13, 1400]];
t.rows.add(null, nouveau);
t.columns.add(null, [
["Total"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"],
["=[Nombre]*[Prix]"]
]);
});
}
async function somme() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
let nouveau = [["", "=SUM(B2:B9)", "=AVERAGE(C2:C9)", "=SUM(D2:D9)"]];
t.rows.add(null, nouveau);
await context.sync();
});
}
async function ajoutJSON() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let tableauJSON = feuille.tables.add("A13:D13", true);
tableauJSON.name = "tableaujson";
tableauJSON.getHeaderRowRange().values = [["Formation", "Nombre", "Prix", "Total"]];
var data = [
{
FORMATION: "Windows 10",
NOMBRE: "1",
PRIX: "950",
TOTAL: "950"
},
{
FORMATION: "Office 2019",
NOMBRE: "2",
PRIX: "1400",
TOTAL: "2800"
}
];
// Conversion du JSON en un tableau
var newData = data.map((item) => [item.FORMATION, item.NOMBRE, item.PRIX, item.TOTAL]);
console.log(newData);
tableauJSON.rows.add(null, newData);
});
}
async function filtre() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
let filtreNombre = t.columns.getItem("Nombre").filter;
filtreNombre.apply({
filterOn: Excel.FilterOn.values,
values: ["1", "2"]
});
});
}
async function stopFiltre() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.clearFilters();
});
}
async function trier() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.sort.apply(
[
{
key: 0,
ascending: true
}
],
true
);
});
}
async function selTitres() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.getHeaderRowRange().select();
});
}
async function selDonnees() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.getDataBodyRange().select();
await context.sync();
});
}
async function selTableau() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.getRange().select();
});
}
async function selColPrix() {
await Excel.run(async function(context) {
let feuille = context.workbook.worksheets.getActiveWorksheet();
let t = feuille.tables.getItem("ventes");
t.columns
.getItem("Prix")
.getRange()
.select();
});
}
/** Default helper for invoking an action and handling errors. */
async function tryCatch(callback) {
try {
await callback();
} catch (error) {
// Note: In a production add-in, you'd want to notify the user through your add-in's UI.
console.error(error);
}
}
language: typescript
template:
content: |-
<button id="creation" class="ms-Button">
<span class="ms-Button-label">Création du tableau</span>
</button>
<button id="ajout" class="ms-Button">
<span class="ms-Button-label">Ajout de données</span>
</button>
<button id="somme" class="ms-Button">
<span class="ms-Button-label">Totaux et moyenne</span>
</button>
<button id="ajoutjson" class="ms-Button">
<span class="ms-Button-label">Ajout de données en JSON</span>
</button>
<button id="filtre" class="ms-Button">
<span class="ms-Button-label">Ventes = 1 ou 2</span>
</button>
<button id="stopfiltre" class="ms-Button">
<span class="ms-Button-label">Supprimer le filtre</span>
</button>
<button id="trier" class="ms-Button">
<span class="ms-Button-label">Tri croissant sur la première colonne</span>
</button>
<button id="seltitres" class="ms-Button">
<span class="ms-Button-label">Sélectionner la ligne de titres</span>
</button>
<button id="seldonnees" class="ms-Button">
<span class="ms-Button-label">Sélectionner les données</span>
</button>
<button id="seltableau" class="ms-Button">
<span class="ms-Button-label">Sélectionner tout le tableau</span>
</button>
<button id="selcolprix" class="ms-Button">
<span class="ms-Button-label">Sélectionner la colonne Prix</span>
</button>
language: html
style:
content: |-
section.samples {
margin-top: 20px;
}
section.samples .ms-Button, section.setup .ms-Button {
display: block;
margin-bottom: 5px;
margin-left: 20px;
min-width: 80px;
}
language: css
libraries: |
https://appsforoffice.microsoft.com/lib/1/hosted/office.js
@types/office-js
office-ui-fabric-js@1.4.0/dist/css/fabric.min.css
office-ui-fabric-js@1.4.0/dist/css/fabric.components.min.css
core-js@2.4.1/client/core.min.js
@types/core-js
jquery@3.1.1
@types/jquery@3.3.1
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment