Advice on coding (1 Viewer)

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
Here is a code that I wrote and I was wondering if anyone can shed some advice if there is a better way of doing this. I am open for suggestions. Please provide helpful advice. Thanks. The code works but I am wondering if I can make it better.

Code:
Private Sub cmdSaveRecord_Click()

'=========== Prompt USER TO ACCEPT RECORD ================

' Confirm to continue
If MsgBox("Do you wish to Accept The Record?", vbYesNo, "Accept Record") = vbNo Then
Exit Sub
End If

On Error GoTo Err_cmdSaveRecord_Click

'Initialize ctl as all Controls in Form
Dim ctl As Control

'============ Check Each Control in Form ============ 

For Each ctl In Me.Controls

        Select Case (ctl.ControlType)          
                                                         
            Case Is = acOptionGroup
            
            If (Me.txtInputOriginalWid = 0 And Me.FrameRevenueOptions.Value = -1) Then
            ' Prompt Warning
            MsgBox "An option for Revision has been Selected.  A Original Worksheet Id is needed.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.SetFocus
            ' Cancel operation
            Cancel = True
            Exit Sub
            
            ElseIf (Me.txtInputOriginalWid > 0 And (Me.FrameRevenueOptions.Value = 0)) Then
            ' Prompt Warning
            MsgBox "A Original Worksheet Id is not valid.  Resetting to 0.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.Value = 0
            ' Set Enabled Property For History Button
            Me.cmdOpenHistory.Enabled = False
            Me.txtInputOriginalWid.Enabled = False
            ' Cancel operation
            Cancel = True
            Exit Sub
                       
            End If

        End Select
Next ctl
'======================== Check if Worksheet has been submitted For a given Period, or 
'======================== Check if A Revision sheet is trying to be submitted before a Original Worksheet Submission For A given Period

    Dim db As DAO.Database
    Set db = CurrentDb
    
    'Dim Table1 As String
    Table1 = "tblFundData"
       
    Dim Query0 As String
    Query0 = "qryDetail"
    
    On Error Resume Next

    ' Delete Querie(s) If exist
    DoCmd.DeleteObject acQuery, Query0
    On Error GoTo 0
    
    Dim qdf0 As DAO.QueryDef
    Dim rst0 As DAO.Recordset
    Dim strSQL0 As String
    Dim passRevision As Boolean
    Dim passTrueUp As Boolean
    Dim periodStart As Date
    Dim periodEnd As Date
    Dim periodLength As Integer
    
    periodStart = Me.txtStartPeriod
    periodEnd = Me.txtEndPeriod
    periodLength = Me.txtPeriodLength

    passRevision = False
    passTrueUp = False
    
    ' Create Sql String From Table1
    strSQL0 = "SELECT ref_id, cid, period_start, period_end, revision, true_up "
    strSQL0 = strSQL0 & "FROM " & Table1 & " "
    strSQL0 = strSQL0 & "WHERE cid = " & Me!txtInputCompanyId.Value & " and "
    strSQL0 = strSQL0 & "period_start = #" & periodStart & "# And period_end = #" & periodEnd & "# And "
    strSQL0 = strSQL0 & "revision = " & passRevision & " And true_up = " & passTrueUp & ";"

    ' Initialize Query
    Set qdf0 = db.CreateQueryDef(Query0, strSQL0)
    Set rst0 = qdf0.OpenRecordset(dbOpenDynaset)
    
    If ((Not rst0.BOF) And (Not rst0.EOF)) Then
    rst0.MoveLast
    End If
    ' Important if you want to get an accurate Record Count
    

    Select Case Me.FrameRevenueOptions.Value

        Case Is = 0
            If rst0.RecordCount >= 1 Then
            Response = MsgBox("An Original Worksheet has already been submitted for this period!", vbOKOnly, "Validation Check")
            'cancel
            Exit Sub
            End If
        Case Is = -1
            If rst0.RecordCount <> 1 Then
            Response = MsgBox("A Revision Worksheet cannot be entered.  An Original Worksheet has not been submitted for this period!", vbOKOnly, "Validation Check")
            'cancel
            Exit Sub
            End If
   
    End Select

    rst0.Close
    Set rst0 = Nothing

'======================== Execute PASS THROUGH QUERY TO REMOTE DATABASE TO UPDATE WORKSHEET

Dim qd As DAO.QueryDef
Dim QueryName As String
Dim passSpName As String
Dim passDateTime As String


QueryName = ""
passSpName = "usp_UpdateTransactions"
passDateTime = Now()

Set db = CurrentDb 'Current Database
Set qd = db.CreateQueryDef(QueryName)

passConnServer = ConnServer ' Calling From Module_Server For Server Connection

'Set Stored Procedure Attributes
With qd
.Connect = SetConnectionString(passConnServer)
.SQL = "Exec " & passSpName & " " & Me.txtTKW_RefId & ", 2, '" & passDateTime & "'"
.ReturnsRecords = False
.Execute
.Close
End With

Set qd = Nothing

'======================== RETREIVE HIGHEST NUMBER IN WID COLUMN and INCREMENT by 1 TO BE USED TO INSERTING A RECORD

Dim rst1 As DAO.Recordset
Dim rst2 As DAO.Recordset

Dim qdf1 As DAO.QueryDef
Dim Query1 As String
Query1 = "qryMaxOfWIDFundData"
   
On Error Resume Next

' Delete Querie(s) If exist
DoCmd.DeleteObject acQuery, Query1
On Error GoTo 0


Dim strSQL As String
Dim newWID As Double

    strSQL = "SELECT Max([wid]) AS maxWid FROM tblFundData;"

    ' Initialize Query
    Set qdf1 = db.CreateQueryDef(Query1, strSQL)
    Set rst1 = qdf1.OpenRecordset(dbOpenDynaset)
    If Not rst1.EOF Then
        newWID = rst1![maxWid] + 1
    End If


'======================== INSERT RECORD IN LOCAL TABLE OF LOCAL DATABASE

    Set rst2 = db.OpenRecordset("tblFundData")
        With rst2
            .AddNew
            rst2![wid] = newWID
            rst2![cid] = Me!txtInputCompanyId.Value
            rst2![submission_date] = Me!txtInputSubmissionDate
            rst2![report_basic_id] = Me!cboReportingBasic.Value
            rst2![report_month] = Me!txtReportingMonth.Value
            rst2![period_start] = periodStart
            rst2![period_end] = periodEnd
            rst2![period_length] = periodLength
            
            'Check if One Time selection is made
            If (Me.FrameRevenueOptions.Value = 2) Then
            rst2![revision] = 0
            rst2![true_up] = 0
            Else
            rst2![revision] = Me.FrameRevenueOptions.Value
            rst2![true_up] = 0
            End If

            rst2![original_wid] = Me!txtInputOriginalWid
            rst2![local_exch_serv] = Me!txtInputLocalExchange
            rst2![late_charge] = Me!txtInputLateFee
            rst2![signature_date] = Me!txtInputCertificationDate
            rst2![signature_name] = UCase(Me!txtInputCertifiedByName)
            .Update
        End With
    
    
    rst1.Close
    rst2.Close
    Set rst1 = Nothing
    Set rst2 = Nothing
    Set db = Nothing

'======================== REQUERY FORM

Forms![frmOnlineSubmission]!sfrmContainerOnlineSubmissionData.Requery

MsgBox ("Record Entered!")


'======================== SEND EMAIL OUT

SendEmailOut "Approved", "", ""

DoCmd.Close


Exit_cmdSaveRecord_Click:
    Exit Sub

Err_cmdSaveRecord_Click:
    MsgBox Err.Description
    Resume Exit_cmdSaveRecord_Click
    
End Sub
 

pbaldy

Wino Moderator
Staff member
Local time
Yesterday, 20:34
Joined
Aug 30, 2003
Messages
36,126
I'll start. What's the purpose of the control loop at the beginning? You don't do anything within the loop that relates to the current control, so why bother? Does it need to run more than once for some reason I'm missing?
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
I'll start. What's the purpose of the control loop at the beginning? You don't do anything within the loop that relates to the current control, so why bother? Does it need to run more than once for some reason I'm missing?

Well after looking at this again, I pulled this piece of code off another form, which I think orginally, I was going through some form controls to make sure the required form control was populated correctly...whether previously I was making sure a dropdown boxes had values and Radio Options had a specific selection. I guess with this code, I dont necessarily have to have it do that now. I can just take that loop out and have it look like this now. I assume this is what you meant.

Original:
Code:
For Each ctl In Me.Controls

        Select Case (ctl.ControlType)          
                                                         
            Case Is = acOptionGroup
            
            If (Me.txtInputOriginalWid = 0 And Me.FrameRevenueOptions.Value = -1) Then
            ' Prompt Warning
            MsgBox "An option for Revision has been Selected.  A Original Worksheet Id is needed.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.SetFocus
            ' Cancel operation
            Cancel = True
            Exit Sub
            
            ElseIf (Me.txtInputOriginalWid > 0 And (Me.FrameRevenueOptions.Value = 0)) Then
            ' Prompt Warning
            MsgBox "A Original Worksheet Id is not valid.  Resetting to 0.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.Value = 0
            ' Set Enabled Property For History Button
            Me.cmdOpenHistory.Enabled = False
            Me.txtInputOriginalWid.Enabled = False
            ' Cancel operation
            Cancel = True
            Exit Sub
                       
            End If

        End Select
Next ctl
Revised:
Code:
            If (Me.txtInputOriginalWid = 0 And Me.FrameRevenueOptions.Value = -1) Then
            ' Prompt Warning
            MsgBox "An option for Revision has been Selected.  A Original Worksheet Id is needed.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.SetFocus
            ' Cancel operation
            Cancel = True
            Exit Sub
            
            ElseIf (Me.txtInputOriginalWid > 0 And (Me.FrameRevenueOptions.Value = 0)) Then
            ' Prompt Warning
            MsgBox "A Original Worksheet Id is not valid.  Resetting to 0.", vbInformation, "Validation Check"
            ' Set Focus
            Me.txtInputOriginalWid.Value = 0
            ' Set Enabled Property For History Button
            Me.cmdOpenHistory.Enabled = False
            Me.txtInputOriginalWid.Enabled = False
            ' Cancel operation
            Cancel = True
            Exit Sub
                       
            End If
 

pbaldy

Wino Moderator
Staff member
Local time
Yesterday, 20:34
Joined
Aug 30, 2003
Messages
36,126
Next, I'm not a fan of deleting/creating an object like you're doing with qryDetail. If appropriate, I'd just change the saved query's SQL. That said, why not just open the recordset on the SQL and avoid the query altogether?

It's a minor thing, but this:

strSQL0 = strSQL0 & "..."

is less efficient than just line continuations:

Code:
strSQL0 = "SELECT... " _
        & "FROM..."
 

vbaInet

AWF VIP
Local time
Today, 04:34
Joined
Jan 22, 2010
Messages
26,374
I was just passing by your thread and thought I should stop by to point out a few things to you ;)

1. The block of code with header:
'======================== Check if Worksheet has been submitted For a given Period, or
'======================== Check if A Revision sheet is trying to be submitted before a Original Worksheet Submission For A given Period

You are only using this function once, no looping so why not just use the DCount() function as below:
Code:
recCount = DCount("*", "Table1", "cid = " & Me!txtInputCompanyId.Value & " AND " & _
                                 "period_start = #" & periodStart & "# And " & _
                                 "period_end = #" & periodEnd & "# And " & _
                                 "revision = " & passRevision & " And true_up = " & passTrueUp)

' Then perform your check here
If recCount = 1 ... etc
2. The block of code with header:
'======================== RETREIVE HIGHEST NUMBER IN WID COLUMN and INCREMENT by 1 TO BE USED TO INSERTING A RECORD

Again this is a one time operation so instead of this
Code:
strSQL = "SELECT Max([wid]) AS maxWid FROM tblFundData;"
You can use this
Code:
nextID = DMax("wid", "tblFunData")
3. Then when you want to INSERT ...
'======================== INSERT RECORD IN LOCAL TABLE OF LOCAL DATABASE

... you can simply execute an UPDATE statement or query. No need for the long lines of inserting data via a recordset.

But just fyi, you used the WITH block with rst2 but never took advantage of it. For example, this is the line I am referring to:
Code:
'======================== INSERT RECORD IN LOCAL TABLE OF LOCAL DATABASE

    Set rst2 = db.OpenRecordset("tblFundData")
        With rst2
            .AddNew
           [COLOR=Red] [/COLOR][COLOR=Red]![/COLOR][wid] = newWID
            [COLOR=Red]![/COLOR][cid] = Me!txtInputCompanyId.Value
            [COLOR=Red]![/COLOR][submission_date] = Me!txtInputSubmissionDate

4. The following code line
Code:
If ((Not rst0.BOF) And (Not rst0.EOF)) Then
... can be written as
Code:
If Not (rs.BOF And rs.EOF) Then
5. Reuse variables and objects. You declared quite a lot of recordset and querydef objects in your code. Create one, reuse that one.

6. This is fyi, if you are going to loop through the controls on your form, be specific about what section you want to loop in. For example I would imagine all the controls you want to loop over were placed in the Detail section, so you can do:
Code:
For Each ctl In Me.Detail.Controls
7. Finally - Layout of your code: Your code could do with some proper indenting. Maybe it's just your style of writing. Also, comments like Set Focus is pretty obvious what the code does there. No need to add such a comment.

Happy coding!
 

MarkK

bit cruncher
Local time
Yesterday, 20:34
Joined
Mar 17, 2004
Messages
8,181
Three things IMO...
Use subroutines.
Use subroutines.
Use subroutines.

- Let's say you declare a bunch of variables and then write a bunch of code. Fine. But if you then declare a new bunch of variables you need to start a new subroutine. I try to write a single subroutine to do a single task, and then name it so that it's stupid obvious what it does.
- I find code easiest to understand when it goes from the abstract to the specific by calling subroutines. Then your controlling code is a list of the large, clearly named functions you will call. Each of those function is likewise, either a list of big clear functions that will be called in turn, or a single task to completion. Simple. Easy to debug. Easy to reuse. Independent snap-in-like components.
- Then your code takes on the shape of the solution and every routine is either a simple procedural list of what will happen, or a single thing happening.

If I was your programming lead I'd want your main routine to look something like this ...
Code:
Private Sub cmdSaveRecord_Click()

   If PromptUserToAccept Then
      If ValidateExistingData Then
         If ConfirmRevisionSheetSubmissionOrder Then
            UpdateWorksheet
            InsertLocalRecord
            RequeryForm
            SendEmail
         Else
            MsgBox "Revision submission order not valid."
         End If
      Else
         MsgBox "Existing data not valid"
      End If
   Else
      MsgBox "User rejected data"
   End If

End Sub
...so in 3 to 5 seconds, looking at this main routine, I can understand the structure of the process.
Code you can understand easily what it does and how it works is code that is more valuable.
That's my 2c,
Mark
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
Next, I'm not a fan of deleting/creating an object like you're doing with qryDetail. If appropriate, I'd just change the saved query's SQL. That said, why not just open the recordset on the SQL and avoid the query altogether?

Hello, pbaldy, Could you explain in detail on what you mean by this? an example on the correct usage?

It's a minor thing, but this:

strSQL0 = strSQL0 & "..."

is less efficient than just line continuations:

Code:
strSQL0 = "SELECT... " _
        & "FROM..."

I did it my way because in the past when I wrote SQL strings, I tend to mess up by not adding a space or mistyping something and it was easier to comment sections of the SQL string to find out where I was messing up.
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
I was just passing by your thread and thought I should stop by to point out a few things to you ;)

1. The block of code with header:
'======================== Check if Worksheet has been submitted For a given Period, or
'======================== Check if A Revision sheet is trying to be submitted before a Original Worksheet Submission For A given Period

You are only using this function once, no looping so why not just use the DCount() function as below:
Code:
recCount = DCount("*", "Table1", "cid = " & Me!txtInputCompanyId.Value & " AND " & _
                                 "period_start = #" & periodStart & "# And " & _
                                 "period_end = #" & periodEnd & "# And " & _
                                 "revision = " & passRevision & " And true_up = " & passTrueUp)

' Then perform your check here
If recCount = 1 ... etc
2. The block of code with header:
'======================== RETREIVE HIGHEST NUMBER IN WID COLUMN and INCREMENT by 1 TO BE USED TO INSERTING A RECORD

Again this is a one time operation so instead of this
Code:
strSQL = "SELECT Max([wid]) AS maxWid FROM tblFundData;"
You can use this
Code:
nextID = DMax("wid", "tblFunData")
3. Then when you want to INSERT ...
'======================== INSERT RECORD IN LOCAL TABLE OF LOCAL DATABASE

... you can simply execute an UPDATE statement or query. No need for the long lines of inserting data via a recordset.

But just fyi, you used the WITH block with rst2 but never took advantage of it. For example, this is the line I am referring to:
Code:
'======================== INSERT RECORD IN LOCAL TABLE OF LOCAL DATABASE

    Set rst2 = db.OpenRecordset("tblFundData")
        With rst2
            .AddNew
           [COLOR=Red]![/COLOR][wid] = newWID
            [COLOR=Red]![/COLOR][cid] = Me!txtInputCompanyId.Value
            [COLOR=Red]![/COLOR][submission_date] = Me!txtInputSubmissionDate
4. The following code line
Code:
If ((Not rst0.BOF) And (Not rst0.EOF)) Then
... can be written as
Code:
If Not (rs.BOF And rs.EOF) Then
5. Reuse variables and objects. You declared quite a lot of recordset and querydef objects in your code. Create one, reuse that one.

6. This is fyi, if you are going to loop through the controls on your form, be specific about what section you want to loop in. For example I would imagine all the controls you want to loop over were placed in the Detail section, so you can do:
Code:
For Each ctl In Me.Detail.Controls
7. Finally - Layout of your code: Your code could do with some proper indenting. Maybe it's just your style of writing. Also, comments like Set Focus is pretty obvious what the code does there. No need to add such a comment.

Happy coding!

Wow, thanks for all those suggestions, very helpful and stuff I can add for my coding techniques.

As for your comment
But just fyi, you used the WITH block with rst2 but never took advantage of it.
Could you explain more in detail?

Thanks again.
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
Three things IMO...
Use subroutines.
Use subroutines.
Use subroutines.

- Let's say you declare a bunch of variables and then write a bunch of code. Fine. But if you then declare a new bunch of variables you need to start a new subroutine. I try to write a single subroutine to do a single task, and then name it so that it's stupid obvious what it does.
- I find code easiest to understand when it goes from the abstract to the specific by calling subroutines. Then your controlling code is a list of the large, clearly named functions you will call. Each of those function is likewise, either a list of big clear functions that will be called in turn, or a single task to completion. Simple. Easy to debug. Easy to reuse. Independent snap-in-like components.
- Then your code takes on the shape of the solution and every routine is either a simple procedural list of what will happen, or a single thing happening.

If I was your programming lead I'd want your main routine to look something like this ...
Code:
Private Sub cmdSaveRecord_Click()

   If PromptUserToAccept Then
      If ValidateExistingData Then
         If ConfirmRevisionSheetSubmissionOrder Then
            UpdateWorksheet
            InsertLocalRecord
            RequeryForm
            SendEmail
         Else
            MsgBox "Revision submission order not valid."
         End If
      Else
         MsgBox "Existing data not valid"
      End If
   Else
      MsgBox "User rejected data"
   End If

End Sub
...so in 3 to 5 seconds, looking at this main routine, I can understand the structure of the process.
Code you can understand easily what it does and how it works is code that is more valuable.
That's my 2c,
Mark

Mark, thanks for the followup suggestions, I know it looks like a mess trying to read it, I will reformat similar to what your are suggesting...which I am sure other posters chiming in where saying something similar.
 

vbaInet

AWF VIP
Local time
Today, 04:34
Joined
Jan 22, 2010
Messages
26,374
As for your comment
Could you explain more in detail?

Thanks again.
Can you see the red exclamation (!) marks in my code? That's how you use the With statement. So if you have a common object between groups of code lines, you can reference the parent object using the With block and complete the reference to the control, method or property by using a dot or an exclamation mark. If you use a dot you get intellisense too. Have a look at the help files.
 

pbaldy

Wino Moderator
Staff member
Local time
Yesterday, 20:34
Joined
Aug 30, 2003
Messages
36,126
Hello, pbaldy, Could you explain in detail on what you mean by this? an example on the correct usage?

No need for any of the QueryDef stuff:

Set rst0 = db.OpenRecordset(strSQL0, dbOpenDynaset)
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
Can you see the red exclamation (!) marks in my code? That's how you use the With statement. So if you have a common object between groups of code lines, you can reference the parent object using the With block and complete the reference to the control, method or property by using a dot or an exclamation mark. If you use a dot you get intellisense too. Have a look at the help files.

I didnt know that. I missed the RED color indicator originally. Thanks.
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
No need for any of the QueryDef stuff:

Set rst0 = db.OpenRecordset(strSQL0, dbOpenDynaset)

When is it necessary to use QueryDef stuff instead of using what you suggested.
 

pbaldy

Wino Moderator
Staff member
Local time
Yesterday, 20:34
Joined
Aug 30, 2003
Messages
36,126
I suppose if you wanted the query to be the source for a form or report or something. I typically only use QueryDef's for pass-through queries. I certainly wouldn't use one in this situation. It doesn't gain you anything, and the extra coding and objects are going to slow things down.
 

accessNator

Registered User.
Local time
Yesterday, 22:34
Joined
Oct 17, 2008
Messages
132
I suppose if you wanted the query to be the source for a form or report or something. I typically only use QueryDef's for pass-through queries. I certainly wouldn't use one in this situation. It doesn't gain you anything, and the extra coding and objects are going to slow things down.

That makes perfect sense. I appreciate the replies as I get a better understanding programming. This helps. I will make my modification accordingly.:)
 

Users who are viewing this thread

Top Bottom