Sub Export2XL(pstrType, plngSubmitterID)
On Error GoTo Err_Handler
Dim db As Database
Dim xlApp As Excel.Application
Dim xlWrkBk As Excel.Workbook
Dim xlSht As Excel.Worksheet
Dim rstTrades As Recordset, rstIntro As Recordset, rstPayments As Recordset
Dim strSQL As String, strSQLDate As String, strDBpath As String, strFolder As String, strPaymentsPath As String, strSQLPayments As String
Dim strSubmitterName As String, strEmail As String, strInvoiceFile As String, strSubject As String, strMessage As String, strSubjectEmail As String
Dim lSubmitterID As Long, lxlRow As Long
Dim strTestPrefix As String
Dim blnEmail As Boolean
Dim curPaid As Currency, curAdvance As Currency, curPrevious As Currency, curInvoice As Currency, curAdj As Currency
'Const strcJetDate = "\#mm\/dd\/yyyy\#" 'Needed for dates in queries as Access expects USA format.Now Public
' Set for testing, remove when live
strTestPrefix = "Test DB "
blnEmail = TempVars("gbEmail")
' Set messages and subject depending on what has been passed
Select Case pstrType
Case "Invoice"
strSubject = strTestPrefix & "Invoice Request"
strMessage = "Would you please supply an invoice for the attached transactions?"
Case "Update"
strSubject = strTestPrefix & "Trade Update"
strMessage = "Please find attached your latest client trades update."
End Select
'strMessage = "Would you please supply an invoice for the attached transactions?"
Set db = CurrentDb()
strDBpath = GetDBPath
'Create new folder if it does not exist
strFolder = Format(Now(), "yyyy-mm-dd")
strPaymentsPath = strDBpath & pstrType & "\" & strFolder & "\"
' Test for path to save files, created each week.
If Dir(strPaymentsPath, vbDirectory) = "" Then
MkDir strPaymentsPath
End If
'Open and reference an instance of the Excel app
Set xlApp = CreateObject("Excel.Application")
xlApp.DisplayAlerts = False
' First get all the Submitters that can have an Invoice Run
' if plngSubmitterID is 0 then we want ALL
If plngSubmitterID = 0 Then
strSQL = "SELECT tblSubmitter.InvoiceRun, tblSubmitter.SubmitterName, tblSubmitter.SubmitterID, tblSubmitter.Email FROM tblSubmitter"
strSQL = strSQL & " WHERE (((tblSubmitter.InvoiceRun)=True))"
strSQL = strSQL & " ORDER BY tblSubmitter.SubmitterName;"
Else
strSQL = "SELECT tblSubmitter.InvoiceRun, tblSubmitter.SubmitterName, tblSubmitter.SubmitterID, tblSubmitter.Email FROM tblSubmitter"
strSQL = strSQL & " WHERE (((tblSubmitter.InvoiceRun)=True) AND (tblSubmitter.SubmitterID = " & plngSubmitterID & "))"
End If
Set rstIntro = db.OpenRecordset(strSQL, dbOpenDynaset)
' Any submitter to process?
If rstIntro.EOF Then
MsgBox "No Submitters found for " & pstrType & " Run"
GoTo ExitSub
End If
' Set date in correct format for query
strSQLDate = Format(TempVars("Invoicedate"), strcJetDate)
' We only need to set this string once for the whole run
strSQLPayments = "SELECT tblPayments.InvoiceDate, tblPayments.InvoiceAmount FROM tblPayments"
strSQLPayments = strSQLPayments & " WHERE (((tblPayments.InvoiceDate)= " & strSQLDate & " AND ((tblPayments.SubmitterID)= " & plngSubmitterID & ")))"
rstIntro.MoveFirst
Do While Not rstIntro.EOF
'Debug.Print rstIntro.Fields("SubmitterName")
strSubmitterName = rstIntro.Fields("SubmitterName")
' need to add submitter name to subject so we can see it in Outlook list
strSubjectEmail = strSubject & " - " & strSubmitterName
strEmail = rstIntro.Fields("Email")
strInvoiceFile = strPaymentsPath & strTestPrefix & strSubmitterName & " " & pstrType & ".xlsx"
' Set submitterID for query
lSubmitterID = rstIntro.Fields("SubmitterID")
' SQL is different depending on Update or Invoice run
If pstrType = "Invoice" Then
strSQL = "SELECT tblSVSTrades.TradeDate, tblSVSTrades.Forename, tblSVSTrades.Surname, tblSVSTrades.TradeType, tblSVSTrades.NetCost, tblSVSTrades.BuySell, tblSubmitter.SubmitterName, tblIntroCommission.IntroCommission,tblIntroCommission.Invoiceddate,tblIntroCommission.PaidDate FROM tblSubmitter"
strSQL = strSQL & " INNER JOIN (tblSubmitterClient INNER JOIN ((tblCommission INNER JOIN tblIntroCommission ON tblCommission.CommissionID = tblIntroCommission.CommissionID) INNER JOIN tblSVSTrades ON tblCommission.TradeID = tblSVSTrades.SVSTradesID) ON tblSubmitterClient.SubmitterClientID = tblIntroCommission.SubmitterClientID) ON tblSubmitter.SubmitterID = tblSubmitterClient.SubmitterID"
strSQL = strSQL & " WHERE (((tblIntroCommission.InvoicedDate) = " & strSQLDate & ") AND ((tblSubmitterClient.SubmitterID)= " & lSubmitterID & "))"
strSQL = strSQL & " ORDER BY tblSVSTrades.SVSTradesID;"
Else
strSQL = "SELECT tblSVSTrades.TradeDate, tblClient.Forename, tblClient.Surname, tblSVSTrades.TradeType, tblSVSTrades.NetCost, tblSVSTrades.BuySell, tblSubmitter.SubmitterName,tblIntroCommission.IntroCommission, tblIntroCommission.InvoicedDate, tblIntroCommission.PaidDate FROM (tblCommission"
strSQL = strSQL & " RIGHT JOIN ((tblClient INNER JOIN (tblSubmitter INNER JOIN tblSubmitterClient ON tblSubmitter.SubmitterID = tblSubmitterClient.SubmitterID) ON tblClient.ClientID = tblSubmitterClient.ClientID)"
strSQL = strSQL & " INNER JOIN tblSVSTrades ON tblClient.SVS_Account = tblSVSTrades.SVSAccount) ON tblCommission.TradeID = tblSVSTrades.SVSTradesID) LEFT JOIN tblIntroCommission ON tblCommission.CommissionID = tblIntroCommission.CommissionID"
strSQL = strSQL & " WHERE (((tblSubmitter.SubmitterID)=" & lSubmitterID & "))"
strSQL = strSQL & " ORDER BY tblSVSTrades.SVSTradesID"
End If
Set rstTrades = db.OpenRecordset(strSQL, dbOpenDynaset)
If Not (rstTrades.BOF And rstTrades.EOF) Then
' Open the Excel Template file
Set xlWrkBk = xlApp.Workbooks.Open(strDBpath & "Introducer Export.xltx")
'reference the first sheet in the file
Set xlSht = xlWrkBk.Sheets(1)
rstTrades.MoveFirst
strSubmitterName = rstTrades.Fields("SubmitterName")
'Update status bar with progress
SetStatusBar ("Retrieving Invoice data for " & strSubmitterName)
lxlRow = 3
Do While Not rstTrades.EOF
' Now enter values in sheet
xlSht.Cells(lxlRow, 1) = rstTrades.Fields("TradeDate")
xlSht.Cells(lxlRow, 2) = rstTrades.Fields("Forename")
xlSht.Cells(lxlRow, 3) = rstTrades.Fields("Surname")
xlSht.Cells(lxlRow, 4) = rstTrades.Fields("TradeType")
xlSht.Cells(lxlRow, 5) = rstTrades.Fields("NetCost")
xlSht.Cells(lxlRow, 6) = rstTrades.Fields("BuySell")
xlSht.Cells(lxlRow, 7) = rstTrades.Fields("SubmitterName")
xlSht.Cells(lxlRow, 8) = rstTrades.Fields("IntroCommission")
' If in Update mode add relevant dates
If pstrType = "Update" Then
xlSht.Cells(lxlRow, 9) = rstTrades.Fields("InvoicedDate")
xlSht.Cells(lxlRow, 10) = rstTrades.Fields("PaidDate")
End If
lxlRow = lxlRow + 1
rstTrades.MoveNext
Loop
lxlRow = lxlRow + 2
xlSht.Cells(lxlRow, 3) = "Date"
xlSht.Cells(lxlRow, 4) = Date
xlSht.Cells(lxlRow, 7) = "Total"
xlSht.Cells(lxlRow, 8) = "=SUM(H3:H" & lxlRow - 2 & ")"
' as we have put the formula in excel we should be able ro read the value instead of summing it ourselves.
curInvoice = xlSht.Cells(lxlRow, 8).Value
' Now check if Castle Invoice run and if so get extra values to apply to invoice
If strSubmitterName = "Castle" Then
curAdvance = GetCastleAmount("Advance")
curPrevious = GetCastleAmount("Previous")
curPaid = GetCastleAmount("Paid")
curAdj = curPrevious - (curAdvance + curPaid)
lxlRow = lxlRow + 2
xlSht.Cells(lxlRow, 6) = "Fact Find Advance"
xlSht.Cells(lxlRow, 6).Font.Bold = True
xlSht.Cells(lxlRow, 8) = curAdj
lxlRow = lxlRow + 2
xlSht.Cells(lxlRow, 6) = "Final Invoice Balance"
xlSht.Cells(lxlRow, 6).Font.Bold = True
xlSht.Cells(lxlRow, 8) = curInvoice + curAdj
End If
' Now autofit columns
xlApp.Columns("A:Z").EntireColumn.AutoFit
SetStatusBar ("Saving Excel workbook " & strInvoiceFile)
' Now save the workbook
xlWrkBk.SaveAs FileName:=strInvoiceFile
xlWrkBk.Close
'Now email the workbook to the Submitter if tempvars gbEmail is true
If blnEmail Then
Call Mail_Attachment(strEmail, strInvoiceFile, strSubjectEmail, strMessage)
End If
Else
SetStatusBar ("No trades for " & strSubmitterName)
End If
' Now close the recordset ready for the next
rstTrades.Close
' Now update Payments table with date and value of invoice for submitter
Set rstPayments = db.OpenRecordset(strSQLPayments, dbOpenDynaset)
' if BOF or EOF then this is the first time of running for this date and submitter
With rstPayments
If .BOF Or .EOF Then
.AddNew
Else
.Edit
End If
.Fields("Invoicedate") = TempVars("Invoicedate")
.Fields("InvoiceAmount") = curInvoice
.Update
End With
rstPayments.Close
' Now get next record
rstIntro.MoveNext
Loop
ExitSub:
xlApp.DisplayAlerts = True
Set db = Nothing
Set rstIntro = Nothing
Set rstTrades = Nothing
Set rstPayments = Nothing
Set xlSht = Nothing
Set xlWrkBk = Nothing
Set xlApp = Nothing
SetStatusBar (" ")
Err_Exit:
Exit Sub
Err_Handler:
MsgBox "Error " & Err.Number & " " & Err.Description
Resume ExitSub
End Sub