Office 脚本示例方案:打孔时钟按钮
此示例中使用的方案理念和脚本由 Office 脚本社区成员 Brian Gonzalez 提供。
在此方案中,你将为员工创建一个时间表,使他们能够使用 按钮记录其开始和结束时间。 根据之前录制的内容,选择该按钮将在) 开始一天 (时钟,或者结束一天 () 。
设置说明
将示例工作簿下载到 OneDrive。
在 Excel 中打开工作簿。
在“ 自动 ”选项卡下,选择“ 新建脚本 ”,并将以下脚本粘贴到编辑器中。
/** * This script records either the start or end time of a shift, * depending on what is filled out in the table. * It is intended to be used with a Script Button. */ function main(workbook: ExcelScript.Workbook) { // Get the first table in the timesheet. const timeSheet = workbook.getWorksheet("MyTimeSheet"); const timeTable = timeSheet.getTables()[0]; // Get the appropriate table columns. const clockInColumn = timeTable.getColumnByName("Clock In"); const clockOutColumn = timeTable.getColumnByName("Clock Out"); const durationColumn = timeTable.getColumnByName("Duration"); // Get the last rows for the Clock In and Clock Out columns. let clockInLastRow = clockInColumn.getRangeBetweenHeaderAndTotal().getLastRow(); let clockOutLastRow = clockOutColumn.getRangeBetweenHeaderAndTotal().getLastRow(); // Get the current date to use as the start or end time. let date: Date = new Date(); // Add the current time to a column based on the state of the table. if (clockInLastRow.getValue() as string === "") { // If the Clock In column has an empty value in the table, add a start time. clockInLastRow.setValue(date.toLocaleString()); } else if (clockOutLastRow.getValue() as string === "") { // If the Clock Out column has an empty value in the table, // add an end time and calculate the shift duration. clockOutLastRow.setValue(date.toLocaleString()); const clockInTime = new Date(clockInLastRow.getValue() as string); const clockOutTime = new Date(clockOutLastRow.getValue() as string); const clockDuration = Math.abs((clockOutTime.getTime() - clockInTime.getTime())); let durationString = getDurationMessage(clockDuration); durationColumn.getRangeBetweenHeaderAndTotal().getLastRow().setValue(durationString); } else { // If both columns are full, add a new row, then add a start time. timeTable.addRow() clockInLastRow.getOffsetRange(1, 0).setValue(date.toLocaleString()); } } /** * A function to write a time duration as a string. */ function getDurationMessage(delta: number) { // Adapted from here: // https://stackoverflow.com/questions/13903897/javascript-return-number-of-days-hours-minutes-seconds-between-two-dates delta = delta / 1000; let durationString = ""; let days = Math.floor(delta / 86400); delta -= days * 86400; let hours = Math.floor(delta / 3600) % 24; delta -= hours * 3600; let minutes = Math.floor(delta / 60) % 60; if (days >= 1) { durationString += days; durationString += (days > 1 ? " days" : " day"); if (hours >= 1 && minutes >= 1) { durationString += ", "; } else if (hours >= 1 || minutes > 1) { durationString += " and "; } } if (hours >= 1) { durationString += hours; durationString += (hours > 1 ? " hours" : " hour"); if (minutes >= 1) { durationString += " and "; } } if (minutes >= 1) { durationString += minutes; durationString += (minutes > 1 ? " minutes" : " minute"); } return durationString; }
将脚本重命名为“打孔时钟”。
保存脚本。
在工作簿中,选择单元格 E2。
添加脚本按钮。 转到“脚本详细信息”页中的“更多选项 (...) ”菜单,然后选择“在工作簿中添加”。
保存工作簿。
运行脚本
选择“ 打孔时钟 ”按钮以运行脚本。 它记录“时钟输入”或“时钟输出”下的当前时间,具体取决于之前输入的内容。
注意
仅当持续时间超过一分钟时才会记录。 手动编辑“时钟输入”时间以测试更长的持续时间。