Solved Problem calculating correct age from birth to death (1 Viewer)

LouL

New member
Local time
Today, 19:57
Joined
Mar 24, 2024
Messages
8
Hello lovely people! I need your help.
I have this code to calculate and display a person's age when they passed away but it's giving me the wrong age, it adds one year to their age!

I first done this in MS Access 2007 now using Access 365
Your help would be appreciated.
Thank you,
Lou

The person was born on: 4th Oct. 1923
and passed away on: 25th May 2021
Her age should have been 97 years and 7 months
NOT 98 years and 7 months
Personal Details Screenshot.jpg

=DateDiff("yyyy",Nz([Death_Ann],Date()),Date())+(Date()<DateSerial(Year(Date()),Month(Nz([Death_Ann],Date())),Day(Nz([Death_Ann],Date())))) & " Years, " & (DateDiff("m",Nz([Death_Ann],Date()),Date())) Mod 12 & " Months Ago"
 

theDBguy

I’m here to help
Staff member
Local time
Today, 02:57
Joined
Oct 29, 2018
Messages
21,473
Hi. I moved your thread out of the introduction forum.

A quick fix is to just subtract one day to the result. Would that work?
 

The_Doc_Man

Immoderate Moderator
Staff member
Local time
Today, 04:57
Joined
Feb 28, 2001
Messages
27,186
The issue, I believe, is that DateDiff will isolate the years before doing the subtraction. (2021-1923 = 98). Take a look at this link, which shows that even one day is enough to want to count another year. (See last sentence in "remarks" section of the link.)


You might have to do a VBA function to return the years/months interval as a string. It gets more complex doing it that way since there are five extra days in the year when you try to compute based on 30-day months.
 

LouL

New member
Local time
Today, 19:57
Joined
Mar 24, 2024
Messages
8
Hi, no, the calculation is out by 1 YEAR!
Her age should have been 97 years and 7 months
NOT 98 years and 7 months
Regards,
Lou
 

LouL

New member
Local time
Today, 19:57
Joined
Mar 24, 2024
Messages
8
The issue, I believe, is that DateDiff will isolate the years before doing the subtraction. (2021-1923 = 98). Take a look at this link, which shows that even one day is enough to want to count another year. (See last sentence in "remarks" section of the link.)



You might have to do a VBA function to return the years/months interval as a string. It gets more complex doing it that way since there are five extra days in the year when you try to compute based on 30-day months.
Thank you,
sorry, I had a look at that but my old grey matter is not what it used to be, I still can't fix my problem from the info there!
Regards,
Lou
 

The_Doc_Man

Immoderate Moderator
Staff member
Local time
Today, 04:57
Joined
Feb 28, 2001
Messages
27,186
Check the first two articles in the "Similar Threads" section below. They might be helpful.
 

GaP42

Active member
Local time
Today, 19:57
Joined
Apr 27, 2020
Messages
338
This may be more than you need but:
Code:
Public Function CalcAge(dteDOB As Date, Optional dteEnd As Date) As String

      'years, months & days
      Dim intYears As Integer, intMonths As Integer, intDays As Integer

      'If no end date supplied, use current date as default
      If Nz(dteEnd, 0) = 0 Then dteEnd = Date

      intMonths = DateDiff("m", dteDOB, dteEnd)
      intDays = DateDiff("d", DateAdd("m", intMonths, dteDOB), dteEnd)

      If intDays < 0 Then
            intMonths = intMonths - 1
            intDays = DateDiff("d", DateAdd("m", intMonths, dteDOB), dteEnd)
      End If

      intYears = intMonths \ 12
      intMonths = intMonths Mod 12
   
Select Case intYears
        Case 0  ' less than 1 yr old
            Select Case intMonths
                Case 0  ' less than one month old
                    Select Case intDays
                        Case 0  ' born today!
                            CalcAge = "Newborn!! today"
                        Case 1
                            CalcAge = intDays & " day old!"
                        Case Else
                            CalcAge = intYears & " Years " & intDays & " days"
                    End Select
                Case 1 ' less than 1 yr --> one month old and x days
                    Select Case intDays
                        Case 0  ' born x months ago! (less than 1 year old)
                            CalcAge = intMonths & "month old"
                        Case 1
                            CalcAge = intMonths & "month and " & intDays & " day old!"
                        Case Else
                            CalcAge = intMonths & " month and " & intDays & " days old"
                    End Select
                Case Else  ' less than one year and greater than one month
                    Select Case intDays
                        Case 0  ' less than 1 year old - born on this day in an earlier month
                            CalcAge = intMonths & " months old"
                        Case 1
                            CalcAge = intMonths & " months and " & intDays & " day"
                        Case Else 'less than 1 year old, earlier month and x days
                            CalcAge = intMonths & " months and " & intDays & " days"
                    End Select
                 
            End Select
        Case 1 ' one year old
            Select Case intMonths
                Case 0  ' less than one month after birthdate
                    Select Case intDays
                        Case 0  ' 1 yr old!
                            CalcAge = "Happy 1st Birthday!!"
                        Case 1
                            CalcAge = intYears & " year and " & intDays & " day old!"
                        Case Else
                            CalcAge = intYears & " years and" & intDays & " days"
                    End Select
                Case 1 ' 1 yr + and one month old and x days
                    Select Case intDays
                        Case 0  ' less than 1-2 year old and 1 month exact)
                            CalcAge = intYears & " year and " & intMonths & "month old"
                        Case 1
                            CalcAge = intYears & " year, " & intMonths & "month and " & intDays & " day old!"
                        Case Else
                            CalcAge = intYears & " year " & intMonths & " month and " & intDays & " days old"
                    End Select
                Case Else  'one year and > 1 month old
                    Select Case intDays
                        Case 0  ' > 1 year old - born on this day in an earlier month
                            CalcAge = intYears & " year and " & intMonths & " months old"
                        Case 1 ' > 1 yr, >1month and on birthday +1
                            CalcAge = intYears & " year and " & intMonths & " months and " & intDays & " day old"
                        Case Else '> 1 year old
                            CalcAge = intYears & " year, " & intMonths & " months and " & intDays & " days"
                    End Select
                 
            End Select
     
        Case Else   ' at least 1 yr old
            Select Case intMonths
                Case 0 ' 0 months
                    Select Case intDays
                        Case 0 ' anniversary - birthdate
                            CalcAge = intYears & " Years - Happy Birthday"
                        Case 1 ' > 1 yr, 0 month and day after birthday
                            CalcAge = intYears & " years and " & intDays & " day old"
                        Case Else ' months not neeeded
                            CalcAge = intYears & " Years, " & intDays & " days"
                    End Select
                Case Else ' > 1 yr and > 1 month
                    Select Case intDays
                        Case 0 ' no days to report
                            CalcAge = intYears & " Years, " & intMonths & " months"
                        Case 1 ' x yr x month + 1 day
                            CalcAge = intYears & " Years, " & intMonths & " months and " & intDays & " day"
                        Case Else '
                            CalcAge = intYears & " Years, " & intMonths & " months and " & intDays & " days"
                    End Select
            End Select
        End Select
     
      'Debug.Print CalcAge

End Function
Pass the birthdate and the date of death to the function. Edit the text for CalcAge to return the string you want. BTW you might want to place an "Age at Death" label next to the control showing the age rather than having "Age:" in the control itself.
You can also use the same function to calculate the "Since Death" age (passing date of death only (as DobDte!!)- it automatically will calculate the time since passing by using the current date - but you will perhaps need to be careful that the text for CalcAge is appropriate for those circumstances (or add the string " ago" to the returned string).
Checking whether the dates are appropriate to pass to the function (eg DobDte < = to the dteEnd) is left to you.
CalcAge(#10/4/1923#, #25/5/2021#)
97 Years, 7 months and 21 days
 
Last edited:

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 17:57
Joined
May 7, 2009
Messages
19,243
you may also try this:
Code:
Public Function Diff2Dates(Interval As String, Date1 As Variant, Date2 As Variant, _
Optional ShowZero As Boolean = False) As Variant
'Author:    ? Copyright 2001 Pacific Database Pty Limited
'           Graham R Seach MCP MVP gseach@pacificdb.com.au
'           Phone: +61 2 9872 9594  Fax: +61 2 9872 9593
'           This code is freeware. Enjoy...
'           (*) Amendments suggested by Douglas J. Steele MVP
'
'Description:   This function calculates the number of years,
'               months, days, hours, minutes and seconds between
'               two dates, as elapsed time.
'
'Inputs:    Interval:   Intervals to be displayed (a string)
'           Date1:      The lower date (see below)
'           Date2:      The higher date (see below)
'           ShowZero:   Boolean to select showing zero elements
'
'Outputs:   On error: Null
'           On no error: Variant containing the number of years,
'               months, days, hours, minutes & seconds between
'               the two dates, depending on the display interval
'               selected.
'           If Date1 is greater than Date2, the result will
'               be a negative value.
'           The function compensates for the lack of any intervals
'               not listed. For example, if Interval lists "m", but
'               not "y", the function adds the value of the year
'               component to the month component.
'           If ShowZero is True, and an output element is zero, it
'               is displayed. However, if ShowZero is False or
'               omitted, no zero-value elements are displayed.
'               For example, with ShowZero = False, Interval = "ym",
'               elements = 0 & 1 respectively, the output string
'               will be "1 month" - not "0 years 1 month".

On Error GoTo Err_Diff2Dates

   Dim booCalcYears As Boolean
   Dim booCalcMonths As Boolean
   Dim booCalcDays As Boolean
   Dim booCalcHours As Boolean
   Dim booCalcMinutes As Boolean
   Dim booCalcSeconds As Boolean
   Dim booCalcWeeks As Boolean
   Dim booSwapped As Boolean
   Dim dtTemp As Date
   Dim intCounter As Integer
   Dim lngDiffYears As Long
   Dim lngDiffMonths As Long
   Dim lngDiffDays As Long
   Dim lngDiffHours As Long
   Dim lngDiffMinutes As Long
   Dim lngDiffSeconds As Long
   Dim lngDiffWeeks As Long
   Dim varTemp As Variant

   Const INTERVALS As String = "dmyhnsw"

'Check that Interval contains only valid characters
   Interval = LCase$(Interval)
   For intCounter = 1 To Len(Interval)
      If InStr(1, INTERVALS, Mid$(Interval, intCounter, 1)) = 0 Then
         Exit Function
      End If
   Next intCounter

'Check that valid dates have been entered
   If IsNull(Date1) Then Exit Function
   If IsNull(Date2) Then Exit Function
   If Not (IsDate(Date1)) Then Exit Function
   If Not (IsDate(Date2)) Then Exit Function

'If necessary, swap the dates, to ensure that
'Date1 is lower than Date2
   If Date1 > Date2 Then
      dtTemp = Date1
      Date1 = Date2
      Date2 = dtTemp
      booSwapped = True
   End If

   Diff2Dates = Null
   varTemp = Null

'What intervals are supplied
   booCalcYears = (InStr(1, Interval, "y") > 0)
   booCalcMonths = (InStr(1, Interval, "m") > 0)
   booCalcDays = (InStr(1, Interval, "d") > 0)
   booCalcHours = (InStr(1, Interval, "h") > 0)
   booCalcMinutes = (InStr(1, Interval, "n") > 0)
   booCalcSeconds = (InStr(1, Interval, "s") > 0)
   booCalcWeeks = (InStr(1, Interval, "w") > 0)

'Get the cumulative differences
   If booCalcYears Then
      lngDiffYears = Abs(DateDiff("yyyy", Date1, Date2)) - _
              IIf(Format$(Date1, "mmddhhnnss") <= Format$(Date2, "mmddhhnnss"), 0, 1)
      Date1 = DateAdd("yyyy", lngDiffYears, Date1)
   End If

   If booCalcMonths Then
      lngDiffMonths = Abs(DateDiff("m", Date1, Date2)) - _
              IIf(Format$(Date1, "ddhhnnss") <= Format$(Date2, "ddhhnnss"), 0, 1)
      Date1 = DateAdd("m", lngDiffMonths, Date1)
   End If

   If booCalcWeeks Then
      lngDiffWeeks = Abs(DateDiff("w", Date1, Date2)) - _
              IIf(Format$(Date1, "hhnnss") <= Format$(Date2, "hhnnss"), 0, 1)
      Date1 = DateAdd("ww", lngDiffWeeks, Date1)
   End If

   If booCalcDays Then
      lngDiffDays = Abs(DateDiff("d", Date1, Date2)) - _
              IIf(Format$(Date1, "hhnnss") <= Format$(Date2, "hhnnss"), 0, 1)
      Date1 = DateAdd("d", lngDiffDays, Date1)
   End If

   If booCalcHours Then
      lngDiffHours = Abs(DateDiff("h", Date1, Date2)) - _
              IIf(Format$(Date1, "nnss") <= Format$(Date2, "nnss"), 0, 1)
      Date1 = DateAdd("h", lngDiffHours, Date1)
   End If

   If booCalcMinutes Then
      lngDiffMinutes = Abs(DateDiff("n", Date1, Date2)) - _
              IIf(Format$(Date1, "ss") <= Format$(Date2, "ss"), 0, 1)
      Date1 = DateAdd("n", lngDiffMinutes, Date1)
   End If

   If booCalcSeconds Then
      lngDiffSeconds = Abs(DateDiff("s", Date1, Date2))
      Date1 = DateAdd("s", lngDiffSeconds, Date1)
   End If

   If booCalcYears And (lngDiffYears > 0 Or ShowZero) Then
      varTemp = lngDiffYears & IIf(lngDiffYears <> 1, " years", " year")
   End If

   If booCalcMonths And (lngDiffMonths > 0 Or ShowZero) Then
      If booCalcMonths Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffMonths & IIf(lngDiffMonths <> 1, " months", " month")
      End If
   End If

   If booCalcWeeks And (lngDiffWeeks > 0 Or ShowZero) Then
      If booCalcWeeks Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffWeeks & IIf(lngDiffWeeks <> 1, " weeks", " week")
      End If
   End If

   If booCalcDays And (lngDiffDays > 0 Or ShowZero) Then
      If booCalcDays Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffDays & IIf(lngDiffDays <> 1, " days", " day")
      End If
   End If

   If booCalcHours And (lngDiffHours > 0 Or ShowZero) Then
      If booCalcHours Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffHours & IIf(lngDiffHours <> 1, " hours", " hour")
      End If
   End If

   If booCalcMinutes And (lngDiffMinutes > 0 Or ShowZero) Then
      If booCalcMinutes Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffMinutes & IIf(lngDiffMinutes <> 1, " minutes", " minute")
      End If
   End If

   If booCalcSeconds And (lngDiffSeconds > 0 Or ShowZero) Then
      If booCalcSeconds Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffSeconds & IIf(lngDiffSeconds <> 1, " seconds", " second")
      End If
   End If

   If booSwapped Then
      varTemp = "-" & varTemp
   End If

   Diff2Dates = Trim$(varTemp)

End_Diff2Dates:
   Exit Function

Err_Diff2Dates:
   Resume End_Diff2Dates

End Function

example:
Code:
diff2dates("ymd",#10/4/1923#,#5/25/2021#,True)


result:

97 years 7 months 21 days
 

LouL

New member
Local time
Today, 19:57
Joined
Mar 24, 2024
Messages
8
you may also try this:
Code:
Public Function Diff2Dates(Interval As String, Date1 As Variant, Date2 As Variant, _
Optional ShowZero As Boolean = False) As Variant
'Author:    ? Copyright 2001 Pacific Database Pty Limited
'           Graham R Seach MCP MVP gseach@pacificdb.com.au
'           Phone: +61 2 9872 9594  Fax: +61 2 9872 9593
'           This code is freeware. Enjoy...
'           (*) Amendments suggested by Douglas J. Steele MVP
'
'Description:   This function calculates the number of years,
'               months, days, hours, minutes and seconds between
'               two dates, as elapsed time.
'
'Inputs:    Interval:   Intervals to be displayed (a string)
'           Date1:      The lower date (see below)
'           Date2:      The higher date (see below)
'           ShowZero:   Boolean to select showing zero elements
'
'Outputs:   On error: Null
'           On no error: Variant containing the number of years,
'               months, days, hours, minutes & seconds between
'               the two dates, depending on the display interval
'               selected.
'           If Date1 is greater than Date2, the result will
'               be a negative value.
'           The function compensates for the lack of any intervals
'               not listed. For example, if Interval lists "m", but
'               not "y", the function adds the value of the year
'               component to the month component.
'           If ShowZero is True, and an output element is zero, it
'               is displayed. However, if ShowZero is False or
'               omitted, no zero-value elements are displayed.
'               For example, with ShowZero = False, Interval = "ym",
'               elements = 0 & 1 respectively, the output string
'               will be "1 month" - not "0 years 1 month".

On Error GoTo Err_Diff2Dates

   Dim booCalcYears As Boolean
   Dim booCalcMonths As Boolean
   Dim booCalcDays As Boolean
   Dim booCalcHours As Boolean
   Dim booCalcMinutes As Boolean
   Dim booCalcSeconds As Boolean
   Dim booCalcWeeks As Boolean
   Dim booSwapped As Boolean
   Dim dtTemp As Date
   Dim intCounter As Integer
   Dim lngDiffYears As Long
   Dim lngDiffMonths As Long
   Dim lngDiffDays As Long
   Dim lngDiffHours As Long
   Dim lngDiffMinutes As Long
   Dim lngDiffSeconds As Long
   Dim lngDiffWeeks As Long
   Dim varTemp As Variant

   Const INTERVALS As String = "dmyhnsw"

'Check that Interval contains only valid characters
   Interval = LCase$(Interval)
   For intCounter = 1 To Len(Interval)
      If InStr(1, INTERVALS, Mid$(Interval, intCounter, 1)) = 0 Then
         Exit Function
      End If
   Next intCounter

'Check that valid dates have been entered
   If IsNull(Date1) Then Exit Function
   If IsNull(Date2) Then Exit Function
   If Not (IsDate(Date1)) Then Exit Function
   If Not (IsDate(Date2)) Then Exit Function

'If necessary, swap the dates, to ensure that
'Date1 is lower than Date2
   If Date1 > Date2 Then
      dtTemp = Date1
      Date1 = Date2
      Date2 = dtTemp
      booSwapped = True
   End If

   Diff2Dates = Null
   varTemp = Null

'What intervals are supplied
   booCalcYears = (InStr(1, Interval, "y") > 0)
   booCalcMonths = (InStr(1, Interval, "m") > 0)
   booCalcDays = (InStr(1, Interval, "d") > 0)
   booCalcHours = (InStr(1, Interval, "h") > 0)
   booCalcMinutes = (InStr(1, Interval, "n") > 0)
   booCalcSeconds = (InStr(1, Interval, "s") > 0)
   booCalcWeeks = (InStr(1, Interval, "w") > 0)

'Get the cumulative differences
   If booCalcYears Then
      lngDiffYears = Abs(DateDiff("yyyy", Date1, Date2)) - _
              IIf(Format$(Date1, "mmddhhnnss") <= Format$(Date2, "mmddhhnnss"), 0, 1)
      Date1 = DateAdd("yyyy", lngDiffYears, Date1)
   End If

   If booCalcMonths Then
      lngDiffMonths = Abs(DateDiff("m", Date1, Date2)) - _
              IIf(Format$(Date1, "ddhhnnss") <= Format$(Date2, "ddhhnnss"), 0, 1)
      Date1 = DateAdd("m", lngDiffMonths, Date1)
   End If

   If booCalcWeeks Then
      lngDiffWeeks = Abs(DateDiff("w", Date1, Date2)) - _
              IIf(Format$(Date1, "hhnnss") <= Format$(Date2, "hhnnss"), 0, 1)
      Date1 = DateAdd("ww", lngDiffWeeks, Date1)
   End If

   If booCalcDays Then
      lngDiffDays = Abs(DateDiff("d", Date1, Date2)) - _
              IIf(Format$(Date1, "hhnnss") <= Format$(Date2, "hhnnss"), 0, 1)
      Date1 = DateAdd("d", lngDiffDays, Date1)
   End If

   If booCalcHours Then
      lngDiffHours = Abs(DateDiff("h", Date1, Date2)) - _
              IIf(Format$(Date1, "nnss") <= Format$(Date2, "nnss"), 0, 1)
      Date1 = DateAdd("h", lngDiffHours, Date1)
   End If

   If booCalcMinutes Then
      lngDiffMinutes = Abs(DateDiff("n", Date1, Date2)) - _
              IIf(Format$(Date1, "ss") <= Format$(Date2, "ss"), 0, 1)
      Date1 = DateAdd("n", lngDiffMinutes, Date1)
   End If

   If booCalcSeconds Then
      lngDiffSeconds = Abs(DateDiff("s", Date1, Date2))
      Date1 = DateAdd("s", lngDiffSeconds, Date1)
   End If

   If booCalcYears And (lngDiffYears > 0 Or ShowZero) Then
      varTemp = lngDiffYears & IIf(lngDiffYears <> 1, " years", " year")
   End If

   If booCalcMonths And (lngDiffMonths > 0 Or ShowZero) Then
      If booCalcMonths Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffMonths & IIf(lngDiffMonths <> 1, " months", " month")
      End If
   End If

   If booCalcWeeks And (lngDiffWeeks > 0 Or ShowZero) Then
      If booCalcWeeks Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffWeeks & IIf(lngDiffWeeks <> 1, " weeks", " week")
      End If
   End If

   If booCalcDays And (lngDiffDays > 0 Or ShowZero) Then
      If booCalcDays Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffDays & IIf(lngDiffDays <> 1, " days", " day")
      End If
   End If

   If booCalcHours And (lngDiffHours > 0 Or ShowZero) Then
      If booCalcHours Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffHours & IIf(lngDiffHours <> 1, " hours", " hour")
      End If
   End If

   If booCalcMinutes And (lngDiffMinutes > 0 Or ShowZero) Then
      If booCalcMinutes Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffMinutes & IIf(lngDiffMinutes <> 1, " minutes", " minute")
      End If
   End If

   If booCalcSeconds And (lngDiffSeconds > 0 Or ShowZero) Then
      If booCalcSeconds Then
         varTemp = varTemp & IIf(IsNull(varTemp), Null, " ") & _
                   lngDiffSeconds & IIf(lngDiffSeconds <> 1, " seconds", " second")
      End If
   End If

   If booSwapped Then
      varTemp = "-" & varTemp
   End If

   Diff2Dates = Trim$(varTemp)

End_Diff2Dates:
   Exit Function

Err_Diff2Dates:
   Resume End_Diff2Dates

End Function

example:
Code:
diff2dates("ymd",#10/4/1923#,#5/25/2021#,True)


result:

97 years 7 months 21 days
Thank you, I was able to do what I wanted to do with that code! :)
Regards,
Lou
 

raziel3

Registered User.
Local time
Today, 05:57
Joined
Oct 5, 2017
Messages
275
I think everyone pretty much covered your problem but just one more small thing. Try to limit the use of the Nz() function. If in the future you want to migrate to SQL or something else, it would be a real headache.

IsNull is a better alternative.
 

LouL

New member
Local time
Today, 19:57
Joined
Mar 24, 2024
Messages
8
I think everyone pretty much covered your problem but just one more small thing. Try to limit the use of the Nz() function. If in the future you want to migrate to SQL or something else, it would be a real headache.

IsNull is a better alternative.
Thank you for your advice, I'll keep that in mind. :)
Regards,
Lou
 

GPGeorge

Grover Park George
Local time
Today, 02:57
Joined
Nov 25, 2004
Messages
1,867
I think everyone pretty much covered your problem but just one more small thing. Try to limit the use of the Nz() function. If in the future you want to migrate to SQL or something else, it would be a real headache.

IsNull is a better alternative.
Except IsNull() in SQL Server TSQL is a different function from IsNull() in Access SQL, so maybe it's not so clearcut.

TSQL IsNull(Expression, Replacement Value) -- This function replaces NULL with the specified replacement value.

In TSQL:

SELECT IsNull([ValueThatIsMissing], "Surprise") FROM YourTable returns "Surprise" if one of the values in the specified field, [ValueThatIsMissing], is null or it returns the value in that field in that record.

Access SQL IsNull() Returns True or False.

In Access SQL:

SELECT IsNull([YourFieldNameGoesHere]) AS TestCase FROM YourTable
returns True or False, depending on whether there is a Null or a NonNull value in the fields in YourTable.

SELECT IsNull([YourFieldNameGoesHere], "Good") AS TestCase FROM YourTable raises an error in Access.
 

Users who are viewing this thread

Top Bottom