1+ /**
2+ * @OnlyCurrentDoc Limits the script to only accessing the spreadsheet it's bound to.
3+ */
4+
5+ const CONFIG = {
6+ REVIEW_STATUS : "Review Status" ,
7+ REVIEWER_EMAIL : "Reviewer Email" ,
8+ TIMESTAMP : "Review Timestamp" ,
9+ NOTES : "Review Notes" ,
10+ STATUS_IN_PROGRESS : "In Progress" ,
11+ LOCK_TIMEOUT : 30000 , // 30 seconds
12+ REQUIRED_COLUMNS : [ "Review Status" , "Reviewer Email" , "Review Timestamp" , "Review Notes" ] ,
13+ VALID_DECISIONS : new Set ( [ "True" , "False" , "Unsure" ] )
14+ } ;
15+
16+ function doGet ( e ) {
17+ const sheetId = PropertiesService . getScriptProperties ( ) . getProperty ( 'SHEET_ID' ) ;
18+ if ( ! sheetId ) {
19+ return HtmlService . createHtmlOutput (
20+ '<b>Error:</b> Spreadsheet ID not configured. Please set the SHEET_ID script property.'
21+ ) ;
22+ }
23+
24+ try {
25+ SpreadsheetApp . openById ( sheetId ) . getName ( ) ; // Test access
26+ return HtmlService . createTemplateFromFile ( 'Index' )
27+ . evaluate ( )
28+ . setTitle ( 'Sheet Row Reviewer' )
29+ . addMetaTag ( 'viewport' , 'width=device-width, initial-scale=1' ) ;
30+ } catch ( err ) {
31+ Logger . log ( "Error accessing Sheet ID '%s': %s" , sheetId , err ) ;
32+ return HtmlService . createHtmlOutput (
33+ `<b>Error:</b> Cannot access Spreadsheet with ID: ${ sheetId } . Check ID and permissions. Error: ${ err . message } `
34+ ) ;
35+ }
36+ }
37+
38+ /**
39+ * Gets the next available row for review and assigns it to the current user.
40+ * Uses LockService for concurrency control.
41+ * @return {object } Response containing row data or error/message
42+ */
43+ function getNextRowToReview ( ) {
44+ const userEmail = Session . getActiveUser ( ) . getEmail ( ) ;
45+ if ( ! userEmail ) {
46+ Logger . log ( 'Could not get user email.' ) ;
47+ return { error : "Could not identify the current user. Please ensure you are logged into a Google Account." } ;
48+ }
49+
50+ const lock = LockService . getScriptLock ( ) ;
51+ try {
52+ if ( ! lock . tryLock ( CONFIG . LOCK_TIMEOUT ) ) {
53+ Logger . log ( 'Could not obtain lock to get next row.' ) ;
54+ return { error : "Could not get a lock to find the next row. Server might be busy. Please try again." } ;
55+ }
56+
57+ const ss = SpreadsheetApp . openById ( PropertiesService . getScriptProperties ( ) . getProperty ( 'SHEET_ID' ) ) ;
58+ const sheet = ss . getActiveSheet ( ) ;
59+ const headerData = getOrAddHeaders_ ( sheet ) ;
60+
61+ if ( ! headerData . success ) {
62+ throw new Error ( headerData . error ) ;
63+ }
64+
65+ const lastRow = sheet . getLastRow ( ) ;
66+ if ( lastRow <= 1 ) {
67+ return { message : "No data rows found in the sheet." } ;
68+ }
69+
70+ // Efficiently get status and reviewer columns
71+ const statusCol = headerData . indices [ CONFIG . REVIEW_STATUS ] + 1 ;
72+ const reviewerCol = headerData . indices [ CONFIG . REVIEWER_EMAIL ] + 1 ;
73+ const reviewRange = sheet . getRange ( 2 , Math . min ( statusCol , reviewerCol ) , lastRow - 1 ,
74+ Math . abs ( statusCol - reviewerCol ) + 1 ) ;
75+ const reviewData = reviewRange . getValues ( ) ;
76+
77+ // Find first unreviewed row
78+ let nextRowIndex = - 1 ;
79+ for ( let i = 0 ; i < reviewData . length ; i ++ ) {
80+ const [ status , reviewer ] = statusCol < reviewerCol ? reviewData [ i ] : reviewData [ i ] . reverse ( ) ;
81+ if ( ! status ) {
82+ nextRowIndex = i + 2 ;
83+ break ;
84+ }
85+ }
86+
87+ if ( nextRowIndex === - 1 ) {
88+ return { message : "All rows have been reviewed or assigned." } ;
89+ }
90+
91+ // Assign row to user
92+ sheet . getRange ( nextRowIndex , statusCol ) . setValue ( CONFIG . STATUS_IN_PROGRESS ) ;
93+ sheet . getRange ( nextRowIndex , reviewerCol ) . setValue ( userEmail ) ;
94+
95+ // Release lock before reading full row data
96+ lock . releaseLock ( ) ;
97+
98+ // Get complete row data
99+ const rowRange = sheet . getRange ( nextRowIndex , 1 , 1 , sheet . getLastColumn ( ) ) ;
100+ const rowData = rowRange . getValues ( ) [ 0 ] ;
101+
102+ Logger . log ( `Assigned row ${ nextRowIndex } to ${ userEmail } ` ) ;
103+ return {
104+ rowIndex : nextRowIndex ,
105+ headers : headerData . headers ,
106+ rowData : rowData
107+ } ;
108+
109+ } catch ( error ) {
110+ Logger . log ( `Error in getNextRowToReview: ${ error } ` ) ;
111+ return { error : `An error occurred: ${ error . message } ` } ;
112+ } finally {
113+ if ( lock . hasLock ( ) ) {
114+ lock . releaseLock ( ) ;
115+ }
116+ }
117+ }
118+
119+ /**
120+ * Submits the review data for a specific row.
121+ * @param {number } rowIndex Row being reviewed (1-based)
122+ * @param {string } decision Review decision ('True', 'False', 'Unsure')
123+ * @param {string } notes Reviewer notes
124+ * @return {object } Success status and optional message
125+ */
126+ function submitReview ( rowIndex , decision , notes ) {
127+ const userEmail = Session . getActiveUser ( ) . getEmail ( ) ;
128+ if ( ! userEmail ) {
129+ Logger . log ( 'Could not get user email for submission.' ) ;
130+ return { success : false , message : "Could not identify the current user for submission." } ;
131+ }
132+
133+ if ( ! rowIndex || ! CONFIG . VALID_DECISIONS . has ( decision ) ) {
134+ Logger . log ( `Invalid submission data: rowIndex=${ rowIndex } , decision=${ decision } ` ) ;
135+ return { success : false , message : "Invalid submission data received." } ;
136+ }
137+
138+ try {
139+ const ss = SpreadsheetApp . openById ( PropertiesService . getScriptProperties ( ) . getProperty ( 'SHEET_ID' ) ) ;
140+ const sheet = ss . getActiveSheet ( ) ;
141+ const headerData = getOrAddHeaders_ ( sheet ) ;
142+
143+ if ( ! headerData . success ) {
144+ throw new Error ( headerData . error ) ;
145+ }
146+
147+ // Get column indices
148+ const columns = {
149+ status : headerData . indices [ CONFIG . REVIEW_STATUS ] + 1 ,
150+ reviewer : headerData . indices [ CONFIG . REVIEWER_EMAIL ] + 1 ,
151+ timestamp : headerData . indices [ CONFIG . TIMESTAMP ] + 1 ,
152+ notes : headerData . indices [ CONFIG . NOTES ] + 1
153+ } ;
154+
155+ // Optional ownership verification
156+ const currentReviewer = sheet . getRange ( rowIndex , columns . reviewer ) . getValue ( ) ;
157+ const currentStatus = sheet . getRange ( rowIndex , columns . status ) . getValue ( ) ;
158+
159+ if ( currentReviewer !== userEmail || currentStatus !== CONFIG . STATUS_IN_PROGRESS ) {
160+ Logger . log ( `Warning: Row ${ rowIndex } submission ownership mismatch. Current: ${ currentReviewer } , Status: ${ currentStatus } ` ) ;
161+ }
162+
163+ // Update all fields at once
164+ const range = sheet . getRange ( rowIndex , columns . status , 1 , 4 ) ;
165+ range . setValues ( [ [
166+ decision ,
167+ userEmail ,
168+ new Date ( ) ,
169+ notes || ""
170+ ] ] ) ;
171+
172+ SpreadsheetApp . flush ( ) ;
173+ Logger . log ( `Review submitted for row ${ rowIndex } by ${ userEmail } : ${ decision } ` ) ;
174+ return { success : true } ;
175+
176+ } catch ( error ) {
177+ Logger . log ( `Error in submitReview for row ${ rowIndex } : ${ error } ` ) ;
178+ return { success : false , message : `An error occurred while submitting: ${ error . message } ` } ;
179+ }
180+ }
181+
182+ /**
183+ * Ensures required columns exist and returns their indices
184+ * @param {Sheet } sheet The sheet to check/modify
185+ * @return {object } Header information and status
186+ */
187+ function getOrAddHeaders_ ( sheet ) {
188+ try {
189+ const headerRange = sheet . getRange ( 1 , 1 , 1 , sheet . getMaxColumns ( ) ) ;
190+ const headers = headerRange . getValues ( ) [ 0 ] . map ( h => String ( h ) . trim ( ) ) ;
191+ const headerIndices = { } ;
192+ const missingCols = [ ] ;
193+ let nextCol = headers . length ;
194+
195+ // Find existing headers and identify missing ones
196+ CONFIG . REQUIRED_COLUMNS . forEach ( colName => {
197+ const index = headers . findIndex ( h => h === colName ) ;
198+ if ( index !== - 1 ) {
199+ headerIndices [ colName ] = index ;
200+ } else {
201+ missingCols . push ( colName ) ;
202+ headerIndices [ colName ] = nextCol ++ ;
203+ }
204+ } ) ;
205+
206+ // Add missing columns if needed
207+ if ( missingCols . length > 0 ) {
208+ Logger . log ( "Adding missing columns: " + missingCols . join ( ', ' ) ) ;
209+ const currentCols = sheet . getMaxColumns ( ) ;
210+ const neededCols = Math . max ( ...Object . values ( headerIndices ) ) + 1 ;
211+
212+ if ( neededCols > currentCols ) {
213+ sheet . insertColumnsAfter ( currentCols , neededCols - currentCols ) ;
214+ }
215+
216+ missingCols . forEach ( colName => {
217+ sheet . getRange ( 1 , headerIndices [ colName ] + 1 ) . setValue ( colName ) ;
218+ } ) ;
219+
220+ // Refresh headers after adding new columns
221+ const updatedHeaders = sheet . getRange ( 1 , 1 , 1 , neededCols ) . getValues ( ) [ 0 ] ;
222+ return {
223+ success : true ,
224+ headers : updatedHeaders ,
225+ indices : headerIndices
226+ } ;
227+ }
228+
229+ return {
230+ success : true ,
231+ headers : headers ,
232+ indices : headerIndices
233+ } ;
234+
235+ } catch ( error ) {
236+ Logger . log ( `Error in getOrAddHeaders_: ${ error } ` ) ;
237+ return {
238+ success : false ,
239+ error : `Failed to set up review columns: ${ error . message } `
240+ } ;
241+ }
242+ }
0 commit comments