amendment wanted,

sumsaam

Board Regular
Joined
Dec 31, 2012
Messages
82
Office Version
  1. 2010
Platform
  1. Windows
Hi,
I got this code by searching on internet, and i use to count my store inventory by scanning there barcodes, We scan Barcodes in H1 cell, it searches that if barcodes list i pasted having the scanned barcode it increases the quantity of that item, if we scan a new barcode(not in pasted barcode list), it puts it at end of my list.
I facing a problem, mostly during counting i have to scan 10 or 20 pcs of same barcode is very time taking,
I want that a check box in excel sheet labeled "quantity mode". if i check the box "quantity mode" it should appear a box prompting for quantity after scanning a barcode, and if i uncheck the box it should take one scan as one pcs automatically.

the code i here


Private Sub Worksheet_Change(ByVal Target As Range)

Const SCAN_CELL As String = "H1"
Const RANGE_BC As String = "A2:A5000"
Dim val, f As Range, rngCodes As Range

If Target.Cells.Count > 1 Then Exit Sub
If Intersect(Target, Me.Range(SCAN_CELL)) Is Nothing Then Exit Sub

val = Trim(Target.Value)
If Len(val) = 0 Then Exit Sub

Set rngCodes = Me.Range(RANGE_BC)

Set f = rngCodes.Find(val, , xlValues, xlWhole)
If Not f Is Nothing Then
With f.Offset(0, 2)
.Value = .Value + 1
End With
Else
Set f = rngCodes.Cells(rngCodes.Cells.Count).End(xlUp).Offset(1, 0)
f.Value = val
f.Offset(0, 1).Value = "enter description"
f.Offset(0, 2).Value = 1
End If

Application.EnableEvents = False
Target.Value = ""
Application.EnableEvents = True

Target.Select

End Sub
 
Hi,

When posting code try to remember to use code tags - it's preserves the formatting making the code easier to read and amend. You use code tags like this:

[code=rich]
your code here
[/code]

For 2 - I've added some code that nearly does what you want (i'll leave you to customise the title and text. If you want to have custom text for the buttons then you will need to employ a userform - I'll also leave you to investigate that option more if needed.

Additions are in red.

Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)

Const SCAN_CELL As String = "H1"
Const RANGE_BC As String = "A2:A5000"
Dim val, f As Range, rngCodes As Range, qty As Variant, QtyMode As Boolean

If Target.Cells.Count > 1 Then Exit Sub
If Intersect(Target, Me.Range(SCAN_CELL)) Is Nothing Then Exit Sub

val = Trim(Target.Value)
If Len(val) = 0 Then Exit Sub

QtyMode = Me.Shapes("Check Box 1").OLEFormat.Object.Value = 1

'If QtyMode Then qty = Application.InputBox("Enter the qty", Type:=1)
If QtyMode Then qty = Application.InputBox(prompt:="Enter the Qty of " & val, Title:="Quantity box", Default:=1, Type:=1)

If Not qty Then
    Set rngCodes = Me.Range(RANGE_BC)
    Set f = rngCodes.Find(val, , xlValues, xlWhole)
        If Not f Is Nothing Then
            With f.Offset(0, 2)
                .Value = .Value + IIf(QtyMode, qty, 1)
            End With
        Else
            If MsgBox("Item not scanned before, add anyway?", vbYesNo + vbInformation) = vbYes Then
                Set f = rngCodes.Cells(rngCodes.Cells.Count).End(xlUp).Offset(1, 0)
                f.Value = val
                f.Offset(0, 1).Value = "enter description"
                f.Offset(0, 2).Value = IIf(QtyMode, qty, 1)
            End If
    End If
End If

Application.EnableEvents = False
Target.Value = ""
Application.EnableEvents = True

Target.Select

End Sub
 
Last edited:
Upvote 0

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top