Đồng bộ dữ liệu Từ MS EXCEL lên GOOGLE SHEET – SYNC Data from Excel to Google sheet

Giáo án link chia sẽ đến các bạn project về Đồng bộ dữ liệu Từ MS EXCEL lên GOOGLE SHEET – SYNC Data from Excel to Google sheet. Tiện ích của project này là chúng đa sẽ đồng bộ dữ liệu từ MS Excel tên Sheet của google, bạn có thể sửa chữa, cập nhật các dữ liệu trên excel, có hiển thị trạng thái các dòng dữ liệu… Bạn xem clip hướng dẫn bên dưới và có code để các bạn tham khảo.

Xem những bài học excel ứng dụng:

Mã code “Code.gs”

var spSheet = SpreadsheetApp.getActiveSpreadsheet();
var dataSheet = spSheet.getSheetByName("Form Responses 1") /*responses từ Google Form*/
var finalSheet = spSheet.getSheetByName("Data") /*sheet contains data*/
var lastRowFinalSheet;
var curRowNo;


function syncWithExcel() {
  /*Variables according to columns of spreadsheet "Form Responses 1" exclude column A*/  
  var fname="";  
  var age = "";
  var occupation = "";  
  var uniqueID="";
  var toBeDeleted = "";
  var dataRow=0;
  
  var lastRowRespSheet = dataSheet.getLastRow();
  
  fname = dataSheet.getRange("B" + lastRowRespSheet).getDisplayValue();  
  age = dataSheet.getRange("C" + lastRowRespSheet).getDisplayValue();
  occupation = dataSheet.getRange("D" + lastRowRespSheet).getDisplayValue();
  uniqueID = dataSheet.getRange("E" + lastRowRespSheet).getDisplayValue();
  toBeDeleted = dataSheet.getRange("F" + lastRowRespSheet).getDisplayValue();
  lastRowFinalSheet = finalSheet.getLastRow();
  

  var dataPresent = idExists(uniqueID)
  
  /*Check ID*/
  if (dataPresent==true) {
    dataRow = curRowNo;
    if (toBeDeleted == "Yes"){ /*If status = yes to delete */
       
       finalSheet.getRange(dataRow + ":" + dataRow).activate();
       finalSheet.deleteRows(spSheet.getActiveRange().getRow(), spSheet.getActiveRange().getNumRows());
      
    }
    else /*Update data */
    {
      finalSheet.getRange("A" + dataRow).setValue(fname)      
      finalSheet.getRange("B" + dataRow).setValue(age)
      finalSheet.getRange("C" + dataRow).setValue(occupation)
      finalSheet.getRange("D" + dataRow).setValue(uniqueID)
      spSheet.refreshAllDataSources();
    }
  }
  else /* Add new data */
  { 
    dataRow = (finalSheet.getLastRow())  + 1;    
    
     finalSheet.getRange("A" + dataRow).setValue(fname)    
     finalSheet.getRange("B" + dataRow).setValue(age)
     finalSheet.getRange("C" + dataRow).setValue(occupation)
     finalSheet.getRange("D" + dataRow).setValue(uniqueID)
     spSheet.refreshAllDataSources();
   
  }
  
}

function  idExists(identifier)
{
  curRowNo = 2 /*Data begin at row 2*/
  var uniqueID = ""
  
  for (var rowNo = 2;rowNo <= lastRowFinalSheet;rowNo++)
  {
    uniqueID=finalSheet.getRange("D" + rowNo).getDisplayValue();
    curRowNo=rowNo
    if(identifier==uniqueID){
      return true;
    }
  }
  return false;
}

Mã code “VBA trong Modul 1 của MS Excel”

'Declare global variables
Global deletedFlag
Dim arrRowsToBeDeleted()
Dim intArrSize

Sub syncWithGS()

    intArrSize = 0

    deletedFlag = False

    ThisWorkbook.Sheets("Data").Range("BZ1").Value = "=countA(A:A)" 'BZ1 contains the value of CountA

    intTotalRows = ThisWorkbook.Sheets("Data").Range("BZ1").Value

    strName = ""    

    strAge = ""

    strOccu = ""

    strToBeDeleted = ""

    strStatus = ""

    strUniqueID = ThisWorkbook.Sheets("Data").Range("BA1").Text 'BA1 contains the start ID value

    Set http = CreateObject("MSXML2.ServerXMLHTTP")

    strBaseURL = "https://docs.google.com/forms/d/e/1FAIpQLScoGoh2Pf7ursMmrIZ2y69CbTFk0acJsMGw3tjti-pEPmNcFw/formResponse?"  ' Link to the google Form created

   For rowNo = 2 To intTotalRows 'Remove the header line

        strRowUniqueID = ""

        strName = ThisWorkbook.Sheets("Data").Range("A" & rowNo).Text
        strAge = ThisWorkbook.Sheets("Data").Range("B" & rowNo).Text
        strOccu = ThisWorkbook.Sheets("Data").Range("C" & rowNo).Text
        strRowUniqueID = ThisWorkbook.Sheets("Data").Range("D" & rowNo).Text
        strToBeDeleted = ThisWorkbook.Sheets("Data").Range("E" & rowNo).Text
        strStatus = ThisWorkbook.Sheets("Data").Range("F" & rowNo).Text            
        

        If strStatus <> "SYNCED" Then 'Check for synchronization

            If strRowUniqueID = "" Then

                 strUniqueID = strUniqueID + 1

                 ThisWorkbook.Sheets("Data").Range("BA1") = strUniqueID

            Else

                strUniqueID = strRowUniqueID

            End If            
            
            strURL = strBaseURL & "&entry.351478222=" & strName
            strURL = strURL & "&entry.1352972907=" & strAge
            strURL = strURL & "&entry.1419041009=" & strOccu
            strURL = strURL & "&entry.733377683=" & strUniqueID
            strURL = strURL & "&entry.1626805838=" & strToBeDeleted

            http.Open "POST", strURL, False

            http.send

            strResponse = http.statusText

            Application.Wait DateAdd("s", 2, Now)

            If strResponse = "OK" Then

                If strToBeDeleted = "Yes" Then 'Check the delete property

                    deletedFlag = True

                    ReDim Preserve arrRowsToBeDeleted(intArrSize)

                    arrRowsToBeDeleted(intArrSize) = rowNo

                    intArrSize = intArrSize + 1

                Else

                    ThisWorkbook.Sheets("Data").Range("F" & rowNo) = "SYNCED"

                    ThisWorkbook.Sheets("Data").Range("D" & rowNo) = strUniqueID

                End If

            End If

        End If

    Next

    Call DeleteRows

    MsgBox "Done"

End Sub
'The function deletes the line if the delete attribute is asserted
Function DeleteRows()

    If deletedFlag = True Then

            For arrRowNo = UBound(arrRowsToBeDeleted) To 0 Step -1

            ThisWorkbook.Sheets("Data").Select

            ThisWorkbook.Sheets("Data").Rows(arrRowsToBeDeleted(arrRowNo) & ":" & arrRowsToBeDeleted(arrRowNo)).Select

            Selection.Delete Shift:=xlUp

        Next

    End If

    deletedFlag = False

End Function

Mã code “Trên Workbook MS Excel”

'Worksheet_Change
Private Sub Worksheet_Change(ByVal Target As Range)

    If Not Intersect(Target, Range("A:E")) Is Nothing Then 'Range form A to E without Colomn of Status

        colNo = Target.Column

        If colNo <> 4 And deletedFlag <> True Then

            rowNo = Target.Row

            ThisWorkbook.Sheets("Data").Cells(rowNo, 6) = "" 'Coloum 6 --> Status

        End If

    End If

End Sub

Xem video hướng dẫn cụ thể