Private Sub cmdConfirmBooking_Click()
Const MESSAGE_TEXT = "The booking was unsuccessful due to attempted double-booking of one or more tables."
Dim strSQL As String
Dim strTableNo As String
Dim strTheDate As String
Dim strArrive As String
Dim strDepart As String
Dim lngBookingID As Long
Dim varItem As Variant
On Error GoTo Err_Handler
' get next BookingID value in sequence
lngBookingID = Nz(DMax("BookingID", "Bookings"), 0) + 1
With Me.lstTableAvailability
If .ItemsSelected.Count > 0 Then
For Each varItem In .ItemsSelected
strTheDate = "#" & Format(.Column(1, varItem), "yyyy-mm-dd") & "#"
' only assign earliest time from selected set to strArrive variable
If strArrive = "" Then
strArrive = "#" & Format(.Column(2, varItem), "hh:nn:ss") & "#"
End If
strDepart = "#" & Format(.Column(3, varItem), "hh:nn:ss") & "#"
Next varItem
' build and execute SQL statement to insert new row into Bookings table
strSQL = "INSERT INTO Bookings(BookingID,TheDate,Arrive,Depart) " & _
"VALUES(" & lngBookingID & ", " & strTheDate & "," & strArrive & "," & strDepart & ")"
CurrentDb.Execute strSQL
For Each varItem In .ItemsSelected
' build and execute SQL statement to insert new row into TableBookings table
strTableNo = """" & .ItemData(varItem) & """"
strSQL = "INSERT INTO TableBookings(BookingID,TableNo) " & _
"VALUES(" & lngBookingID & ", " & strTableNo & ")"
CurrentDb.Execute strSQL
' if table or tables double-booked inform user and cancel booking
If IsNull(DLookup("BookingID", "TableBookings", "BookingID = " & lngBookingID)) Then
MsgBox MESSAGE_TEXT, vbExclamation, "Invalid Operation"
strSQL = "DELETE * FROM Bookings WHERE BookingID = " & lngBookingID
CurrentDb.Execute strSQL
' deselect all selected rows from listbox
cmdClearSelections_Click
Exit Sub
End If
Next varItem
End If
End With
' open bookings form in dialogue mode
DoCmd.OpenForm "frmBookings", WhereCondition:="BookingID = " & lngBookingID, WindowMode:=acDialog
' call command button's Click event procedure to clear listbox selections
cmdClearSelections_Click
' requery list box to show new booking
Me.lstTableAvailability.Requery
Exit_Here:
Exit Sub
Err_Handler:
MsgBox Err.Description, vbExclamation, "Error"
End Sub