Extract years between two dates

koolwaters

Active Member
Joined
May 16, 2007
Messages
403
Hi,

I need to extract the years between two dates.

For example:

Start Date 2010-09-07
End Date 2014-08-30

The number of years between the Start Date and End Date are four.

As part of my query result, I need to see only the years between these two dates. So I would see,

2011 2012 2013 2014

If I have
Start Date 2010-09-07
End Date 2013-08-30

I need to see 2011 2012 2013

I hope that someone can assist.

Thanks in advance.
 
Yes. That worked. Thanks!

Just a bit of clarification. In the post below, I was trying to achieve the output in the second table.

Ok. The Sheet below is the output generated by the code you provided.
Excel Workbook
ABCDEFGHIJK
1DepartmentApplicationIDEmployeeIDStartDateEndDateAmountApproved2009 - Amt in (US$)2010 - Amt in (US$)2011 - Amt in (US$)2012 - Amt in (US$)2013 - Amt in (US$)
2Human Resources1114-Sep-0930-Aug-13$ 8,000.002,000.002,000.002,000.002,000.00
3Corporate2201-Mar-1101-Apr-11$ 6,000.006,000.00
4Human Resources3101-Mar-1101-Apr-11$ 6,000.006,000.00
Sheet1
Excel 2007

This is the additional output which I also need.
Excel Workbook
ABCDEFG
7DepartmentAmountApproved2009 - Amt in (US$)2010 - Amt in (US$)2011 - Amt in (US$)2012 - Amt in (US$)2013 - Amt in (US$)
8Human Resources$ 14,000.002,000.008,000.002,000.002,000.00
9Corporate$ 6,000.006,000.00
Sheet1
Excel 2007

So, I need to have summaries by Department.

I hope you can follow.

You provided me with this code which worked but because Department was not in tblApplication, I was getting the prompt for Department when I ran the query.


Hi Michelle,

dynamic tables require dynamic queries,

next code creates a new querydef. Read comments to adjust before you run the code

Code:
Public Sub CreateDynamicQuery()
'Create a querydefinition
'call each time you want to query the data
Dim dbs As DAO.Database
Dim tdf As DAO.TableDef
Dim fld As DAO.Field
Dim qdf As DAO.QueryDef
Dim iFldCnt As Integer
Dim sSumFields() As String
Dim sSQL_Grouped As String
Const sGroupField As String = "EmployeeID" 'This should be Department, but I had this already in the table over here, change to correct field
Const sTblName As String = "ttblForeCast"
Const sTempQueryName As String = "qForeCast"
Set dbs = CurrentDb
Set tdf = dbs.TableDefs(sTblName)
iFldCnt = 0
'Loop fields of forecast table
    For Each fld In tdf.Fields
 
        ReDim Preserve sSumFields(iFldCnt)
 
        Select Case fld.Name
                Case sGroupField
                    sSumFields(iFldCnt) = "[" & fld.Name & "]"
                     iFldCnt = iFldCnt + 1
                Case "ApplicationID", "StartDate", "EndDate" ' , "EmployeeID"     'these are the fields to skip, you need to add the EmployeeID
                'do nothing
                Case Else
                    sSumFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
                    iFldCnt = iFldCnt + 1
        End Select
 
    Next fld
'Construct the sql statement
sSQL_Grouped = "Select " & Join(sSumFields, ", ") & " from " & sTblName & " Group By [" & sGroupField & "]"
'create dynamic querydef
'first delete the query if exists
    For Each qdf In dbs.QueryDefs
        If qdf.Name = sTempQueryName Then dbs.QueryDefs.Delete qdf.Name
    Next qdf
'this creates the querydef in your database
Set qdf = dbs.CreateQueryDef(sTempQueryName, sSQL_Grouped)
 
End Sub

My new question is can I use the modules below, with the necessary changes, to achieve this as well with the totals and all?

Code:
Option Compare Database
Option Explicit

Public Function SQL_ABSYears() As String
Const sTableName As String = "tblApplication"
SQL_ABSYears = "SELECT Min(StartDate) AS FirstStartDate, Max(EndDate) AS LastEndDate " _
             & "FROM " & sTableName
End Function

Public Function SQL_Application() As String
    SQL_Application = "Select * from tblApplication"
End Function

Public Sub CreateTtblBudgetForecast()
Dim dbs As DAO.Database
Dim rs As DAO.Recordset
Dim tdf As DAO.TableDef
Dim sSQL As String
Const sTempTableName As String = "ttblBudgetForecast"
Dim sYears() As String
Dim sYearFlds As String
Dim iFYear As Integer
Dim iLYear As Integer
Dim iCnt As Integer
Dim sAmounts() As String
Dim sAmount As String
Set dbs = CurrentDb
'Delete temptable if exists
For Each tdf In dbs.TableDefs
    If tdf.Name = sTempTableName Then dbs.TableDefs.Delete sTempTableName
Next tdf
'Fetch the absolute first date and last date
Set rs = dbs.OpenRecordset(SQL_ABSYears)
With rs
    If Not .EOF And Not .BOF Then
        .MoveFirst
        iFYear = Year(.Fields("FirstStartDate").Value) ' + 1
        iLYear = Year(.Fields("LastEndDate").Value)
    Else
        MsgBox "No data found", vbExclamation
        Exit Sub
    End If
    .Close
End With

'Create array holding all years between startdate and enddate
'- Amt in (US$)"
For iCnt = 0 To iLYear - iFYear '- 1
    ReDim Preserve sYears(iCnt)
    sYears(iCnt) = "[" & (iFYear + iCnt) & " - Amt in (US$)] Double"
Next iCnt
'Join years for create table sql
sYearFlds = Join(sYears, ", ")
sYearFlds = "ApplicationID Long, EmployeeID Text, StartDate DateTime, EndDate DateTime, AmountApproved Currency, " & sYearFlds
'create the temptable and index
sSQL = "Create Table " & sTempTableName & " (" & sYearFlds & ")"
dbs.Execute sSQL
sSQL = "CREATE UNIQUE INDEX [PrimaryKey] ON " & sTempTableName & " ([ApplicationID])  WITH PRIMARY DISALLOW NULL "
dbs.Execute sSQL
'Section to append data from Application to forecast
Set rs = dbs.OpenRecordset(SQL_Application)
With rs
    .MoveFirst
    Do Until .EOF
    
        'First determine the years to forecast
        sYearFlds = vbNullString
        ReDim sYears(0)
        ReDim sAmounts(0)
        
        iFYear = Year(.Fields("StartDate").Value) + 1
        iLYear = Year(.Fields("EndDate").Value)
        If iFYear > iLYear Then iFYear = iFYear - 1
            
        'create array for years to append
        For iCnt = 0 To iLYear - iFYear '- 1
            ReDim Preserve sYears(iCnt)
            ReDim Preserve sAmounts(iCnt)
            sYears(iCnt) = "[" & (iFYear + iCnt) & " - Amt in (US$)]"
            sAmounts(iCnt) = "'" & .Fields("AmountApproved").Value / (iLYear - (iFYear - 1)) & "'"
        Next iCnt
        sYearFlds = Join(sYears, ", ")
        sAmount = Join(sAmounts, ", ")
        'construct the insert statment
        
        sSQL = "Insert Into " & sTempTableName & "(ApplicationID, EmployeeID, StartDate, EndDate, AmountApproved, " & sYearFlds & ")" _
             & "Values (" & .Fields("ApplicationID").Value & ", '" & .Fields("EmployeeID").Value & "', #" & .Fields("StartDate").Value & "#, #" & .Fields("EndDate").Value & "#, '" & .Fields("AmountApproved").Value & "', " & sAmount & ")"
        'insert values into temptable
        dbs.Execute sSQL
    .MoveNext
    Loop
End With

CreateQryBudgetForecast

End Sub

Code:
Option Compare Database
Option Explicit

Public Const sTrail As String = " - Amt in (US$)" 'Trail string for field names yearly amounts

Public Sub MainCaller()
Const sLinkFieldOne As String = "ApplicationID"             'Fldname of PK of sTblNameForeCast
Const sTblNameForeCast As String = "ttblApplicationsForEMCApproval"           'Name of the created temptable
Const sLinkFieldTwo As String = "ApplicationID"             'Fldname of FK in sQueryToLinkName
Const sQueryToLinkName As String = "qryApplication" 'The query with all fields to display except the yearly amounts, and having the ApplicationID field in the select statement
Const sTempQueryName As String = "qryApplicationsForEMCApproval"                'The name of the query to built
Dim blnSumAmounts As Boolean   'Switch to tell routine if the results need to be grouped and thus needing to sum and group fields.
Dim sSumThisFlds As String     'If you want a summarized result, then specifify the fields that need to be summed, except for the yearly dynamic fields
                               'All fields that are not summed, will automatically be the group fields
blnSumAmounts = True         'Switch to false if you don't want summarized results
sSumThisFlds = "AmountApproved"
BuiltTableWithQuery sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sTempQueryName, blnSumAmounts, sSumThisFlds
End Sub

Public Sub BuiltTableWithQuery(ByVal sQueryToLinkName As String, _
                               ByVal sTblNameForeCast As String, _
                               ByVal sLinkFieldOne As String, _
                               ByVal sLinkFieldTwo As String, _
                               ByVal sTempQueryName As String, _
                               ByVal blnSumAmounts As Boolean, _
                               Optional ByVal sSumThisFlds As String = "")
 
'Routine that creates all entities
'1 create the forecast table
'2 create array with fieldnames
'3 create the querydef
Dim sAmtYFlds As String     'String to hold the dynamic fieldnames for comparison
Dim dbs As DAO.Database
Dim tdf As DAO.TableDef
Dim fld As DAO.Field
Dim qdf As DAO.QueryDef
Dim rs As DAO.Recordset
Dim iFldCnt As Integer
Dim sFields() As String
Dim sSumFields() As String
Dim sSQL As String
Dim s As String
Dim sSelFlds As String
Dim sGroupFlds As String
Dim sFlds As String
 
'Create the forecast table
CreateTempTable sTblNameForeCast
Set dbs = CurrentDb
'Get the fieldnames from the QueryToLink, ignore the link fields
Set qdf = dbs.QueryDefs(sQueryToLinkName)
iFldCnt = 0
For Each fld In qdf.Fields
 
        'Test if fld = sum field
        If blnSumAmounts And InStr(1, sSumThisFlds, fld.Name, vbTextCompare)<> 0 Then 'It's a sum field
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
            iFldCnt = iFldCnt + 1
        ElseIf fld.Name = sLinkFieldOne Or fld.Name = sLinkFieldTwo Then
            'Ignore field
        Else
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "[" & fld.Name & "]"
            If blnSumAmounts Then sGroupFlds = sGroupFlds & ", " & "[" & fld.Name & "]"
 
            iFldCnt = iFldCnt + 1
        End If
Next fld
Set tdf = dbs.TableDefs(sTblNameForeCast)
'load all amtFlds from function
sAmtYFlds = sAmountYearFields
'test if current fieldname is in the sAmtYFlds string
'extract year amount fieldnames from tempforecast into array
'This is to eliminate all fields other than the dynamic fields
For Each fld In tdf.Fields
        If InStr(1, sAmtYFlds, fld.Name, vbTextCompare) > 0 Then
        ReDim Preserve sFields(iFldCnt)
            If blnSumAmounts Then
                sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            Else
                sFields(iFldCnt) = "[" & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            End If
        End If
Next fld
sSelFlds = Join(sFields, ", ")
sSQL = SQL_JoinTwoTbls(sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sSelFlds, Mid(sGroupFlds, 3))
'test if the query already exists, if so delete
    For Each qdf In dbs.QueryDefs
        If qdf.Name = sTempQueryName Then dbs.QueryDefs.Delete qdf.Name
    Next qdf
 
Set qdf = dbs.CreateQueryDef(sTempQueryName, sSQL)
End Sub

Public Function sAmountYearFields() As String
'creates a string with all possible values for dynamic field name regarding amounts using the const sTrail
'result = 2000/../2100 - Amt in (US$)
Dim sY(100) As String '100 years forward, if you still use this system by then, maybe it's time to update
Dim sFlds As String   'string for result
Dim yCnt As Long      'counter for years
Const iFY As Long = 2000 'starting year
For yCnt = 0 To UBound(sY)
    sY(yCnt) = iFY + yCnt & sTrail
Next yCnt
sAmountYearFields = Join(sY, ", ")
End Function

Public Function SQL_JoinTwoTbls(ByVal sTblOne As String, _
                                ByVal sTblTwo As String, _
                                ByVal sJoinFldOne As String, _
                                ByVal sJoinFldTwo As String, _
                                ByVal sSelFlds As String, _
                                Optional ByVal sGroupFlds As String)
 
'String function which creates a join between two tables
'Within this context, a table can also be a queryDef
Dim sSQL As String
If Len(sGroupFlds)<> 0 Then
    sGroupFlds = "Group By " & sGroupFlds
End If
sSQL = "Select " & sSelFlds & " " _
      & "FROM " & sTblOne & " INNER JOIN " & sTblTwo & " ON " & sTblOne & "." & sJoinFldOne & " = " & sTblTwo & "." & sJoinFldTwo & " " _
      & sGroupFlds
 
SQL_JoinTwoTbls = sSQL
End Function
 
Upvote 0

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
You need to forget all code I posted earlier, the two new modules do everything you need.

All you need to change are the names of the queries you use in de maincaller. (and create the queries of course)
You can even switch to summarize or don't summarize.
blnSumAmounts = True or blnSumAmounts = false
 
Upvote 0
The only thing missing is the AmountApproved column which is needed in this one.

I tried to play around with it but I am still not seeing in in the table or the query.

Here is the code I used.

Code:
Option Compare Database
Option Explicit

Public Function SQL_ABSYears() As String
Const sTableName As String = "tblApplication"
SQL_ABSYears = "SELECT Min(StartDate) AS FirstStartDate, Max(EndDate) AS LastEndDate " _
             & "FROM " & sTableName
End Function

Public Function SQL_Application() As String
    SQL_Application = "Select * from tblApplication"
End Function

Public Sub CreateBudgetForecastTable(ByVal sTblNameForeCast As String)
'Creates forecast table with fields:
'ApplicationID
'YearAmountFields for each year
Dim dbs As DAO.Database
Dim rs As DAO.Recordset
Dim tdf As DAO.TableDef
Dim sSQL As String
Dim sYears() As String
Dim sYearFlds As String
Dim iFYear As Integer
Dim iLYear As Integer
Dim iCnt As Integer
Dim sAmounts() As String
Dim sAmountValues As String
Set dbs = CurrentDb
'Delete temptable if exists
For Each tdf In dbs.TableDefs
    If tdf.Name = sTblNameForeCast Then dbs.TableDefs.Delete sTblNameForeCast
Next tdf
'Fetch the absolute first date and last date
Set rs = dbs.OpenRecordset(SQL_ABSYears)
With rs
    If Not .EOF And Not .BOF Then
        .MoveFirst
        iFYear = Year(.Fields("FirstStartDate").Value) ' + 1
        iLYear = Year(.Fields("LastEndDate").Value)
    Else
        MsgBox "No data found", vbExclamation
        Exit Sub
    End If
    .Close
End With
'Create array holding all years between startdate and enddate
For iCnt = 0 To iLYear - iFYear
    ReDim Preserve sYears(iCnt)
    sYears(iCnt) = "[" & (iFYear + iCnt) & sTrail & "] Double"
Next iCnt
'Join years for create table sql
sYearFlds = Join(sYears, ", ")
sYearFlds = "ApplicationID Long, AmountApproved Currency," & sYearFlds
'create the temptable and index
sSQL = "Create Table " & sTblNameForeCast & " (" & sYearFlds & ")"
dbs.Execute sSQL
sSQL = "CREATE UNIQUE INDEX [PrimaryKey] ON " & sTblNameForeCast & " ([ApplicationID])  WITH PRIMARY DISALLOW NULL "
dbs.Execute sSQL
'Section to append data from Application to forecast
Set rs = dbs.OpenRecordset(SQL_Application)
With rs
    .MoveFirst
    Do Until .EOF
        'First determine the years to forecast
        sYearFlds = vbNullString
        ReDim sYears(0)
        ReDim sAmounts(0)
        iFYear = Year(.Fields("StartDate").Value) + 1
        iLYear = Year(.Fields("EndDate").Value)
        If iFYear > iLYear Then iFYear = iFYear - 1
        'create array for years to append
        For iCnt = 0 To iLYear - iFYear
            ReDim Preserve sYears(iCnt)
            ReDim Preserve sAmounts(iCnt)
            sYears(iCnt) = "[" & (iFYear + iCnt) & " - Amt in (US$)]"
            sAmounts(iCnt) = "'" & Round(.Fields("AmountApproved").Value / (iLYear - (iFYear - 1)), 2) & "'"
        Next iCnt
 
        sYearFlds = Join(sYears, ", ")
        sAmountValues = Join(sAmounts, ", ")
        'construct the insert statement
        sSQL = "Insert Into " & sTblNameForeCast & "(ApplicationID, AmountApproved," & sYearFlds & ")" _
             & "Values (" & .Fields("ApplicationID").Value & ", " & .Fields("AmountApproved").Value & sAmountValues & ")"
        'insert values into temptable
        dbs.Execute sSQL
    .MoveNext
    Loop
End With
End Sub
 
Upvote 0
This is the second module and this works and summarises the data but it's just that Amount Approved is missing. Is there also away to format all of the amounts approved as Currency?

Code:
Option Compare Database
Option Explicit

Public Const sTrail2 As String = " - Amt in (US$)" 'Trail string for field names yearly amounts

Public Sub MainCaller2()
Const sLinkFieldOne As String = "ApplicationID"             'Fldname of PK of sTblNameForeCast
Const sTblNameForeCast As String = "ttblBudgetForecast"           'Name of the created temptable
Const sLinkFieldTwo As String = "ApplicationID"             'Fldname of FK in sQueryToLinkName
Const sQueryToLinkName As String = "qryBudgetForecast" 'The query with all fields to display except the yearly amounts, and having the ApplicationID field in the select statement
Const sTempQueryName As String = "qrptBudgetForecast"                'The name of the query to built
Dim blnSumAmounts As Boolean   'Switch to tell routine if the results need to be grouped and thus needing to sum and group fields.
Dim sSumThisFlds As String     'If you want a summarized result, then specifify the fields that need to be summed, except for the yearly dynamic fields
                               'All fields that are not summed, will automatically be the group fields
blnSumAmounts = True         'Switch to false if you don't want summarized results
sSumThisFlds = "AmountApproved"
BuiltTableWithQuery2 sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sTempQueryName, blnSumAmounts, sSumThisFlds
End Sub

Public Sub BuiltTableWithQuery2(ByVal sQueryToLinkName As String, _
                               ByVal sTblNameForeCast As String, _
                               ByVal sLinkFieldOne As String, _
                               ByVal sLinkFieldTwo As String, _
                               ByVal sTempQueryName As String, _
                               ByVal blnSumAmounts As Boolean, _
                               Optional ByVal sSumThisFlds As String = "")
 
'Routine that creates all entities
'1 create the forecast table
'2 create array with fieldnames
'3 create the querydef
Dim sAmtYFlds As String     'String to hold the dynamic fieldnames for comparison
Dim dbs As DAO.Database
Dim tdf As DAO.TableDef
Dim fld As DAO.Field
Dim qdf As DAO.QueryDef
Dim rs As DAO.Recordset
Dim iFldCnt As Integer
Dim sFields() As String
Dim sSumFields() As String
Dim sSQL As String
Dim s As String
Dim sSelFlds As String
Dim sGroupFlds As String
Dim sFlds As String
 
'Create the forecast table
CreateTempTable sTblNameForeCast
Set dbs = CurrentDb
'Get the fieldnames from the QueryToLink, ignore the link fields
Set qdf = dbs.QueryDefs(sQueryToLinkName)
iFldCnt = 0
For Each fld In qdf.Fields
 
        'Test if fld = sum field
        If blnSumAmounts And InStr(1, sSumThisFlds, fld.Name, vbTextCompare) <> 0 Then 'It's a sum field
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
            iFldCnt = iFldCnt + 1
        ElseIf fld.Name = sLinkFieldOne Or fld.Name = sLinkFieldTwo Then
            'Ignore field
        Else
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "[" & fld.Name & "]"
            If blnSumAmounts Then sGroupFlds = sGroupFlds & ", " & "[" & fld.Name & "]"
 
            iFldCnt = iFldCnt + 1
        End If
Next fld
Set tdf = dbs.TableDefs(sTblNameForeCast)
'load all amtFlds from function
sAmtYFlds = sAmountYearFields
'test if current fieldname is in the sAmtYFlds string
'extract year amount fieldnames from tempforecast into array
'This is to eliminate all fields other than the dynamic fields
For Each fld In tdf.Fields
        If InStr(1, sAmtYFlds, fld.Name, vbTextCompare) > 0 Then
        ReDim Preserve sFields(iFldCnt)
            If blnSumAmounts Then
                sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            Else
                sFields(iFldCnt) = "[" & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            End If
        End If
Next fld
sSelFlds = Join(sFields, ", ")
sSQL = SQL_JoinTwoTbls(sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sSelFlds, Mid(sGroupFlds, 3))
'test if the query already exists, if so delete
    For Each qdf In dbs.QueryDefs
        If qdf.Name = sTempQueryName Then dbs.QueryDefs.Delete qdf.Name
    Next qdf
 
Set qdf = dbs.CreateQueryDef(sTempQueryName, sSQL)
End Sub

Public Function sAmountYearFields2() As String
'creates a string with all possible values for dynamic field name regarding amounts using the const sTrail
'result = 2000/../2100 - Amt in (US$)
Dim sY(100) As String '100 years forward, if you still use this system by then, maybe it's time to update
Dim sFlds As String   'string for result
Dim yCnt As Long      'counter for years
Const iFY As Long = 2000 'starting year
For yCnt = 0 To UBound(sY)
    sY(yCnt) = iFY + yCnt & sTrail
Next yCnt
sAmountYearFields2 = Join(sY, ", ")
End Function

Public Function SQL_JoinTwoTbls2(ByVal sTblOne As String, _
                                ByVal sTblTwo As String, _
                                ByVal sJoinFldOne As String, _
                                ByVal sJoinFldTwo As String, _
                                ByVal sSelFlds As String, _
                                Optional ByVal sGroupFlds As String)
 
'String function which creates a join between two tables
'Within this context, a table can also be a queryDef
Dim sSQL As String
If Len(sGroupFlds) <> 0 Then
    sGroupFlds = "Group By " & sGroupFlds
End If
sSQL = "Select " & sSelFlds & " " _
      & "FROM " & sTblOne & " INNER JOIN " & sTblTwo & " ON " & sTblOne & "." & sJoinFldOne & " = " & sTblTwo & "." & sJoinFldTwo & " " _
      & sGroupFlds
 
SQL_JoinTwoTbls2 = sSQL
End Function
 
Upvote 0
the amount approved has to be in your query qryBudgetForecast.
Regarding formating, it is possible. I'll post something later on.
 
Upvote 0
For the formatting, replace sub BuiltTableWithQuery

for this one

Code:
Public Sub BuiltTableWithQuery(ByVal sQueryToLinkName As String, _
                               ByVal sTblNameForeCast As String, _
                               ByVal sLinkFieldOne As String, _
                               ByVal sLinkFieldTwo As String, _
                               ByVal sTempQueryName As String, _
                               ByVal blnSumAmounts As Boolean, _
                               Optional ByVal sSumThisFlds As String = "")
 
'Routine that creates all entities
'1 create the forecast table
'2 create array with fieldnames
'3 create the querydef
Dim sAmtYFlds As String     'String to hold the dynamic fieldnames for comparison
Dim dbs As DAO.Database
Dim tdf As DAO.TableDef
Dim fld As DAO.Field
Dim qdf As DAO.QueryDef
Dim rs As DAO.Recordset
Dim iFldCnt As Integer
Dim sFields() As String
Dim sSQL As String
Dim sSelFlds As String
Dim sGroupFlds As String
'Create the forecast table
CreateTempTable sTblNameForeCast
Set dbs = CurrentDb
'Get the fieldnames from the QueryToLink, ignore the link fields
Set qdf = dbs.QueryDefs(sQueryToLinkName)
iFldCnt = 0
For Each fld In qdf.Fields
 
        'Test if fld = sum field
        If blnSumAmounts And InStr(1, sSumThisFlds, fld.Name, vbTextCompare) <> 0 Then 'It's a sum field
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
            iFldCnt = iFldCnt + 1
        ElseIf fld.Name = sLinkFieldOne Or fld.Name = sLinkFieldTwo Then
            'Ignore field
        Else
            ReDim Preserve sFields(iFldCnt)
            sFields(iFldCnt) = "[" & fld.Name & "]"
            If blnSumAmounts Then sGroupFlds = sGroupFlds & ", " & "[" & fld.Name & "]"
 
            iFldCnt = iFldCnt + 1
        End If
Next fld
Set tdf = dbs.TableDefs(sTblNameForeCast)
'load all amtFlds from function
sAmtYFlds = sAmountYearFields
'test if current fieldname is in the sAmtYFlds string
'extract year amount fieldnames from tempforecast into array
'This is to eliminate all fields other than the dynamic fields
For Each fld In tdf.Fields
        If InStr(1, sAmtYFlds, fld.Name, vbTextCompare) > 0 Then
        ReDim Preserve sFields(iFldCnt)
            If blnSumAmounts Then
                sFields(iFldCnt) = "Sum([" & fld.Name & "]) as [Total " & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            Else
                sFields(iFldCnt) = "[" & fld.Name & "]"
                iFldCnt = iFldCnt + 1
            End If
        End If
Next fld
sSelFlds = Join(sFields, ", ")
sSQL = SQL_JoinTwoTbls(sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sSelFlds, Mid(sGroupFlds, 3))
'test if the query already exists, if so delete
    For Each qdf In dbs.QueryDefs
        If qdf.Name = sTempQueryName Then dbs.QueryDefs.Delete qdf.Name
    Next qdf
 
Set qdf = dbs.CreateQueryDef(sTempQueryName, sSQL)
[COLOR=red][B]'formatting, hard coded for only the amount approved field
Dim prp As DAO.Property
For Each fld In qdf.Fields
    If InStr(1, fld.Name, "AmountApproved", vbTextCompare) <> 0 Then
        Set prp = fld.CreateProperty("Format", dbText, "€ * #,##0.00")
                fld.Properties.Append prp
    End If
Next fld
[/B][/COLOR]End Sub
 
Upvote 0
One more thing, I see you made a copy of the complete module and renamed the subs. You don't need to do this.
The only part you should copy is the maincaller.

Example

Code:
Public Sub Create_qrptBudgetForecast()
Dim sLinkFieldOne As String     'Fldname of PK of sTblNameForeCast
Dim sTblNameForeCast As String  'Name of the created temptable
Dim sLinkFieldTwo As String     'Fldname of FK in sQueryToLinkName
Dim sQueryToLinkName As String  'The query with all fields to display except the yearly amounts, and having the ApplicationID field in the select statement
Dim sTempQueryName As String    'The name of the query to built
Dim blnSumAmounts As Boolean    'Switch to tell routine if the results need to be grouped and thus needing to sum and group fields.
Dim sSumThisFlds As String      'If you want a summarized result, then specifify the fields that need to be summed, except for the yearly dynamic fields
                                'All fields that are not summed, will automatically be the group fields
blnSumAmounts = True            'Switch to false if you don't want summarized results
sLinkFieldOne = "ApplicationID"
sTblNameForeCast "ttblBudgetForecast"
sLinkFieldTwo = "ApplicationID"
sQueryToLinkName = "qryBudgetForecast"
sTempQueryName = "qrptBudgetForecast"
sSumThisFlds = "AmountApproved"
BuiltTableWithQuery sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sTempQueryName, blnSumAmounts, sSumThisFlds
End Sub

and the other one

Code:
Public Sub Create_qryApplicationsForEMCApproval()
Dim sLinkFieldOne As String     'Fldname of PK of sTblNameForeCast
Dim sTblNameForeCast As String  'Name of the created temptable
Dim sLinkFieldTwo As String     'Fldname of FK in sQueryToLinkName
Dim sQueryToLinkName As String  'The query with all fields to display except the yearly amounts, and having the ApplicationID field in the select statement
Dim sTempQueryName As String    'The name of the query to built
Dim blnSumAmounts As Boolean    'Switch to tell routine if the results need to be grouped and thus needing to sum and group fields.
Dim sSumThisFlds As String      'If you want a summarized result, then specifify the fields that need to be summed, except for the yearly dynamic fields
                                'All fields that are not summed, will automatically be the group fields
blnSumAmounts = True            'Switch to false if you don't want summarized results
sLinkFieldOne = "ApplicationID"
sTblNameForeCast "ttblApplicationsForEMCApproval"
sLinkFieldTwo = "ApplicationID"
sQueryToLinkName = "qryApplication"
sTempQueryName = "qryApplicationsForEMCApproval"
sSumThisFlds = "AmountApproved"
BuiltTableWithQuery sQueryToLinkName, sTblNameForeCast, sLinkFieldOne, sLinkFieldTwo, sTempQueryName, blnSumAmounts, sSumThisFlds
End Sub
 
Upvote 0
Thanks for your replies. I will implement the changes later today.

I may be asking you some questions when I go through the code and figure out exactly what is being done.

I was working on this for a while but it was requested to have the reports completed by Monday so I have not gone through the code in detail.

Thanks very much as you have been a great help. I know I would not have gotten this done without help.
 
Upvote 0
I did not realise it was just the MainCaller that I need to modify.

I have corrected this so I now have just 2 modules, modCreateTempQueries and modCreateTempTables. I have just reused the MainCaller adding a number behind it where necessary and adjusted the lines of it.

Everything works perfectly except that the amounts in the columns is not formatted as currency, only the Amount Approved. I assume you were not able to correct this so I will just tell my GM it could not be accomplished and he has to format them manually.

I have a form set up called fdlgExportToExcel with an Option Group, to export the queries created and I call the MailCaller routines from this form, based on the option selected.

Thank you again for all your time and patience. I greatly appreciate it.
 
Upvote 0
Hi Michelle,

of course you can also format the yearly amounts, but I thought you didn't want them formatted with the $ sign as this is already in the header.

But if you replace the format section you already have, it will format the yearly fields as currency, only without the $ sign.

Code:
Dim prp As DAO.Property
For Each fld In qdf.Fields
    If InStr(1, fld.Name, "AmountApproved", vbTextCompare) <> 0 Then
        Set prp = fld.CreateProperty("Format", dbText, "€ * #,##0.00")
                fld.Properties.Append prp
    ElseIf InStr(1, sAmtYFlds, Mid(fld.Name, 7), vbTextCompare) <> 0 Then
        Set prp = fld.CreateProperty("Format", dbText, "#,##0.00")
                fld.Properties.Append prp
    End If
Next fld
 
Upvote 0

Forum statistics

Threads
1,224,522
Messages
6,179,297
Members
452,903
Latest member
Knuddeluff

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top