Results 1 to 3 of 3
  1. #1
    4 Star Lounger
    Join Date
    Feb 2001
    Location
    Louisville, Kentucky, USA
    Posts
    597
    Thanks
    0
    Thanked 0 Times in 0 Posts

    SQL UPDATE Statement (A2K)

    I need to update a field to 0 in a linked table where that field is Null.

    The field in the table is NOT static, each month a field is added to this table, i.e. Mar08Panel, Apr08Panel, May08Panel.

    I don't want the user to have to go into a query and pull down the newest field added and update that field, so I thought about using an SQL UPDATE statement but am struggling to get it to work.

    <pre>Dim mysql As String
    Dim sMth, sYR, sField As String

    sMth = Format(DateSerial(Year(Date), Month(Date) - 2, 1), "mmm")
    sYR = Format(DateSerial(Year(Date), Month(Date) - 2, 1), "yy")
    sField = sMth & sYR & "Panel"

    DoCmd.SetWarnings False

    'mysql = "UPDATE tblPCPPanelSize Set" & sField & " = isnull(" & sField & ", 0)"
    mysql = "UPDATE tblPCPPanelSize SET " & sField & " = 0 WHERE " & sField & " ISNull"
    Debug.Print mysql
    DoCmd.RunSQL mysql

    DoCmd.SetWarnings True</pre>



    However, I continue to get "Missing Operator" error msg. I've tried to change the syntax but still get the msg. Can someone please identify to me what I'm missing?
    Roberta Price <img src=/S/cheers.gif border=0 alt=cheers width=30 height=16>

  2. #2
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 18 Times in 18 Posts

    Re: SQL UPDATE Statement (A2K)

    Instead of ISNull use Is Null (with a space between Is and Null):<code>
    mysql = "UPDATE tblPCPPanelSize SET " & sField & " = 0 WHERE " & sField & " Is Null"
    </code>
    IsNull(...) is a VBA function that returns True or False

    ... Is Null is used in SQL to test the value of a field or expression for being Null.

    BTW, instead of
    <code>
    sMth = Format(DateSerial(Year(Date), Month(Date) - 2, 1), "mmm")
    sYR = Format(DateSerial(Year(Date), Month(Date) - 2, 1), "yy")
    sField = sMth & sYR & "Panel"
    </code>
    you can use
    <code>
    sField = Format(DateSerial(Year(Date), Month(Date) - 2, 1), "mmmyy") & "Panel"</code>

  3. #3
    4 Star Lounger
    Join Date
    Feb 2001
    Location
    Louisville, Kentucky, USA
    Posts
    597
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: SQL UPDATE Statement (A2K)

    Thanks Hans for both suggestions, they work beautifully...
    Roberta Price <img src=/S/cheers.gif border=0 alt=cheers width=30 height=16>

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •