Validation list using code

G

Gareth

My sheet ('Purchases') contains a list of medicines, the code below provides
me with a list of medicines which haven't run out.

The list is put in column A on the 'Medicine in stock' sheet.

Sub Medicineinstock()
With Worksheets("Purchases")
For Each cell In .Range("H2:H" & .Range("H65536").End(xlUp).Row)
If Not IsEmpty(cell.Value) Then
If IsNumeric(cell.Value) Then
If cell.Value > 0 Then
Worksheets("Medicine in stock").Range("A65536").End(xlUp).Offset(1, 0).Value
= cell.Offset(0, -6).Value
End If
End If
End If
Next
End With
End Sub

I want to make a data validation list out of the medicine in stock and apply
that list to the next 20 blank cells in column A on sheet 'Medicine Record'.

My problem is that I want to have the Change Event of that sheet work when
an item in the data validation list is picked and work has Excel '97 and I
believe it doesn't 'fire' in '97.

A previos workaround was to enter the items directly into the control, is it
possible to do this by macro??

Thanks in advance.

Gareth
 
B

Bob Phillips

Gareth,

Data Validation doesn't trigger the Change event in 97, but what you could
do is to set another cell linked to your data validation cell, and have a
calculate event do the work for you. I used this technique to have dynamic
data validation list in XL97.

--

HTH

Bob Phillips
... looking out across Poole Harbour to the Purbecks
(remove nothere from the email address if mailing direct)
 
G

Gareth

If you enter the data validation source into the control it does work (eg -
yes,no,maybe)

what I want to do is get the list of medicines in B2:B? which have >0 in
H2:H? into a data validation list.

Any ideas?

Gareth
 
D

Debra Dalgleish

It may not be a problem in your worksheet, but the delimited list has a
maximum of 255 characters:

'=================================
Sub Medicineinstock()
Dim c As Range
Dim str As String
str = ""
With Worksheets("Purchases")
For Each c In .Range("H2:H" & .Range("H65536").End(xlUp).Row)
If Not IsEmpty(c.Value) Then
If IsNumeric(c.Value) Then
If c.Value > 0 Then
str = str & c.Offset(0, -6).Value & ","
End If
End If
End If
Next
str = Left(str, Len(str) - 1)
str = Left(str, 255)
End With
Debug.Print str
End Sub
'===============================
 
G

Gareth

Debra

Thanks for this, works just great. You are right about the 255 characters
causing a problem though.

Therefore, I would like to try Bob's suggestion of using a linked cell.
Unfortunately I have no idea how to go about it, could anyone please offer
any assistance?

Gareth
 
B

Bob Phillips

Gareth,

Can I just check exactly what you want to do?

You have a list of Purchases on one sheet.
You have a Data Validation cell linked to a list - where is that, is it just
one cell or many?
What do you want to do when the Data Validation is selected from?
Do you want the DV list to update automatically when you change purchases
(e.g. something may come in to/go out of stock)?

--

HTH

Bob Phillips
... looking out across Poole Harbour to the Purbecks
(remove nothere from the email address if mailing direct)
 
G

Gareth

The DV list is applied to column A (or 20 rows at the bottom of the column).

The list is updated before being created (the >0 bit of my macro). What I
want to do is use the change event to use vlookup to get two bits of data
from the Medicines sheet. I cannot use the vlookup formula, it has to be
done by code.

This is why I tried putting the list of medicines straight into the control
but with it having a 255 max of characters it causes a problem.

Hope you understand what I'm after.

Gareth
 
B

Bob Phillips

Gareth,

Have you got your 20 rows of DV aligned to the DV list? I am assuming you
have this, if not just post back.

To get a selection to trigger an event, I will just display values from
'Purchases' in a MsgBox. I think you will be able to use it as you need.

First, let's assume that the DV cells are in A41:A60. Setup links to these
cells somewhere off-stage so to speak.. For instance, in AZ41 input =A41.
This is to fire the Calculate event. Repeat down to A60.

Input this code in the 'Medicines in stock' worksheet code module.

Private Sub Worksheet_Calculate()
Dim sValue
Dim oFind As Range

sValue = ActiveCell.Value
Set oFind = Worksheets("Purchases").Columns(1).Find(sValue)
If oFind Is Nothing Then
MsgBox "Something's wrong!"
Else
MsgBox "Value " & sValue & vbCrLf & _
"Column 2 is " & oFind.Offset(0, 1).Value & vbCrLf & _
"Column 7 is " & oFind.Offset(0, 7).Value
End If

End Sub

Haven't tried this particular solution on XL97, although I have used the
technique before on XL97.

--

HTH

Bob Phillips
... looking out across Poole Harbour to the Purbecks
(remove nothere from the email address if mailing direct)
 
B

Bob Phillips

Just found a basic flaw in the code. It is triggered by any change not just
the DV, so try this

Private Sub Worksheet_Calculate()
Dim sValue
Dim oFind As Range

If Not Intersect(ActiveCell, Range("A41:A60")) Is Nothing Then
sValue = ActiveCell.Value
Set oFind = Worksheets("Purchases").Columns(1).Find(sValue)
If oFind Is Nothing Then
MsgBox "Something's wrong!"
Else
MsgBox "Value " & sValue & vbCrLf & _
"Column 2 is " & oFind.Offset(0, 1).Value & vbCrLf & _
"Column 7 is " & oFind.Offset(0, 7).Value
End If
End If

End Sub



--

HTH

Bob Phillips
... looking out across Poole Harbour to the Purbecks
(remove nothere from the email address if mailing direct)
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top