Macro to compare old prices with new prices for stock and show(-/+)

KalilMe

Active Member
Joined
Mar 5, 2021
Messages
399
Office Version
  1. 2016
Platform
  1. Windows
Hello,
in QW sheet will be multiple columns contain prices and every time I will add new column contain new prices .
in STOCK sheet contains data in columns A:E
what I want create report in columns G:L with formatting and borders by brings the prices from last column in QW sheet and put in column J , as to column K=column I* column J
column L =column K- column E
in lastrow for column G when amount is minus in column L then populate LOSE word ,amount is plus in column L then populate PROFIT word.
if there is empty cell in last column in QW when brings price from previous column(not the first column) for instance if there is price in columnL,M,N and if the id doesn't existed price in column N then will brings from column M .
when create report will match BATCH column for two sheets , also if there is ID in STOCK sheet and it's not existed in QW sheet then will show as in STOCK sheet.


subtra.xlsm
JKLM
1ITEMBATCH01/11/202402/11/2024
21APP PP FRUIT12.0011.00
32BAN FF FRUIT9.00
43CU CMC VEG11.0011.00
54FRU BANN MU22.0023.00
65PI PIA FRUIT21.0021.00
76PO PTT VEG12.0011.00
87TO TMA VEG5.004.00
98TE TEE FOOD23.0018.00
109TRB POT BNG22.0024.00
QW




subtra.xlsm
ABCDEFGHIJKLMNO
1ITEMBATCHQTYUNIT PRICETOTAL
21TO TMA VEG10.005.0050.00
32PO PTT VEG20.0010.00200.00
43BAN FF FRUIT100.0012.001,200.00
54APP PP FRUIT100.0010.001,000.00
65PI PIA FRUIT12.0022.00264.00
76TE TEE FOOD100.0023.002,300.00
87CU CMC VEG120.0021.002,520.00
98TRB POT BNG100.0022.002,200.00
109FRU BANN MU124.0022.002,728.00
11
12
13
14
STOCK



result
subtra.xlsm
ABCDEFGHIJKLMNO
1ITEMBATCHQTYUNIT PRICETOTALITEMBATCHQTYUNIT PRICETOTALD/P
21TO TMA VEG10.005.0050.001TO TMA VEG10.004.0040.00-10.00
32PO PTT VEG20.0010.00200.002PO PTT VEG20.0011.00220.0020.00
43BAN FF FRUIT100.0012.001,200.003BAN FF FRUIT100.009.00900.00-300.00
54APP PP FRUIT100.0010.001,000.004APP PP FRUIT100.0011.001,100.00100.00
65PI PIA FRUIT12.0022.00264.005PI PIA FRUIT12.0021.00252.00-12.00
76TE TEE FOOD100.0023.002,300.006TE TEE FOOD100.0018.001,800.00-500.00
87CU CMC VEG120.0021.002,520.007CU CMC VEG120.0011.001,320.00-1,200.00
98TRB POT BNG100.0022.002,200.008TRB POT BNG100.0024.002,400.00200.00
109FRU BANN MU124.0022.002,728.009FRU BANN MU124.0023.002,852.00124.00
11LOSE-1,578.00
12
13
STOCK
Cell Formulas
RangeFormula
L2:L10L2=K2-E2
L11L11=SUM(L2:L10)

I need macro , I don't PQ or PT , formulas
thanks
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
Try.
VBA Code:
Sub CreateTable()
Application.ScreenUpdating = False
Dim Lrq&, Lrs&, Lcq&, T&, Ta&
Dim Frng1 As Range, Frng2 As Range

Lrq = Sheets("QW").Range("A" & Rows.Count).End(xlUp).Row
Lcq = Sheets("QW").Cells(1, Columns.Count).End(xlToLeft).Column
With Sheets("STOCK")
.Range("G1").CurrentRegion.Clear
Lrs = .Range("A" & Rows.Count).End(xlUp).Row
.Range("A1").CurrentRegion.Resize(, 3).Copy .Range("G1")
For T = 2 To Lrs
Set Frng1 = Sheets("QW").Range("B2:B" & Lrq).Find(.Range("H" & T).Value)
If Not Frng1 Is Nothing Then
    For Ta = Lcq To 3 Step -1
    If Sheets("QW").Cells(Frng1.Row, Ta) <> "" Then
    .Range("J" & T) = Sheets("QW").Cells(Frng1.Row, Ta)
    Exit For
    End If
    Next Ta
End If
Next T
.Range("K2:K" & Lrs).Formula = "=I2*J2"
.Range("L2:L" & Lrs).Formula = "=K2-E2"
.Range("G1:J1").Copy .Range("J1")
.Range("J1:L1") = Array("UNIT PRICE", "TOTAL", "D/P")
.Range("L" & Lrs + 1).Formula = "=Sum(L2:L" & Lrs & ")"
If .Range("L" & Lrs + 1) < 0 Then .Range("G" & Lrs + 1) = "LOSS" Else .Range("G" & Lrs + 1) = "GAIN"
.Range("H1").CurrentRegion.Borders.LineStyle = xlContinuous
End With

Application.ScreenUpdating = True
End Sub
 
Upvote 0
Upvote 0
Col J:L will be blank when BATCH is missing in QW sheet.
Clear Col.B that is the result of wrong cell reference of previous code, otherwise you will get wrong result again.
Code:
Sub test()
    Dim s$(1), i&, x&, r As Range, c As Range, ws As Worksheet
    Application.ScreenUpdating = False
    Set ws = Sheets("stock")
    ws.Columns("g:l").Clear
    With Sheets("qw")
        With .Range("j1", .Cells.SpecialCells(11))
            Set r = .Columns(.Columns.Count + 1)
            r.Cells(1) = "UP"
            r.Cells(2).FormulaArray = Replace("=index(#,max(if(#<>"""",column(#)-9)))", "#", "rc10:rc[-1]")
            r.Cells(2).Resize(r.Rows.Count - 1).FillDown
        End With
    End With
    s(1) = "Provider=Microsoft.Ace.OLEDB.12.0;Data Source=" & _
    ThisWorkbook.FullName & ";Extended Properties='Excel 12.0;HDR=Yes';"
    s(0) = "Select A.`ITEM`, A.`BATCH`, A.`QTY`, B.`UP` As `UNIT PRICE`, " & _
        "A.`QTY` * B.`UP` As `TOTAL`, A.`QTY` * B.`UP` - A.`TOTAL` As `D/P` " & _
        "From `STOCK$` As A Left Join `QW$` As B On A.`BATCH` = B.`BATCH`;"
    With CreateObject("ADODB.Recordset")
        .Open s(0), s(1), 3, 3, 1
        For i = 0 To .Fields.Count - 1
            ws.Cells(1, i + 7) = .Fields(i).Name
        Next
        ws.[g2].CopyFromRecordset .DataSource
    End With
    r.Clear
    With ws.[g1].CurrentRegion
        .HorizontalAlignment = xlCenter
        .Columns("d:l").NumberFormat = "#,0.00"
        Union(.Rows(1), .Rows(.Rows.Count + 1)).Font.Bold = True
        Set c = .Cells(.Rows.Count + 1, .Columns.Count)
        c.Formula = "=sum(r2c:r[-1]c)"
        .Cells(.Rows.Count + 1, 1) = IIf(c > 0, "GAIN", "LOOSE")
        .EntireColumn.AutoFit
        .Resize(.Rows.Count + 1).Borders.Weight = 2
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Clear Col.B that is the result of wrong cell reference of previous code,
I don't understand it!
the new item in STOCK sheet should show even if it's not existed in QW sheet.
 
Upvote 0
I'm talking about the workbook you uploaded.

B1 = UP: B2 = 0 in QW sheet.

You need to clear above, before you run the code.
 
Upvote 0
ok
but doesn't show rest of data for new item in STOCK sheet in row 11
sub.xlsm
ABCDEFGHIJKL
1ITEMBATCHQTYUNIT PRICETOTALITEMBATCHQTYUNIT PRICETOTALD/P
21TO TMA VEG1,000.005.0050.001TO TMA VEG100033.0033,000.0032,950.00
32PO PTT VEG20.0010.00200.002PO PTT VEG2011.00220.0020.00
43BAN FF FRUIT100.0012.001,200.003BAN FF FRUIT1009.00900.00-300.00
54APP PP FRUIT100.0010.001,000.004APP PP FRUIT10011.001,100.00100.00
65PI PIA FRUIT12.0022.00264.005PI PIA FRUIT1221.00252.00-12.00
76TE TEE FOOD100.0023.002,300.006TE TEE FOOD10018.001,800.00-500.00
87CU CMC VEG120.0021.002,520.007CU CMC VEG12011.001,320.00-1,200.00
98TRB POT BNG100.0022.002,200.008TRB POT BNG10024.002,400.00200.00
1010FRU BANN MU124.0022.002,728.0010FRU BANN MU12423.002,852.00124.00
1111FRU we3 MU124.0022.002,728.0011FRU we3 MU124
12GAIN31,382.00
STOCK
Cell Formulas
RangeFormula
L12L12=SUM(L$2:L11)




the right
sub.xlsm
ABCDEFGHIJKL
1ITEMBATCHQTYUNIT PRICETOTALITEMBATCHQTYUNIT PRICETOTALD/P
21TO TMA VEG1,000.005.0050.001TO TMA VEG100033.0033,000.0032,950.00
32PO PTT VEG20.0010.00200.002PO PTT VEG2011.00220.0020.00
43BAN FF FRUIT100.0012.001,200.003BAN FF FRUIT1009.00900.00-300.00
54APP PP FRUIT100.0010.001,000.004APP PP FRUIT10011.001,100.00100.00
65PI PIA FRUIT12.0022.00264.005PI PIA FRUIT1221.00252.00-12.00
76TE TEE FOOD100.0023.002,300.006TE TEE FOOD10018.001,800.00-500.00
87CU CMC VEG120.0021.002,520.007CU CMC VEG12011.001,320.00-1,200.00
98TRB POT BNG100.0022.002,200.008TRB POT BNG10024.002,400.00200.00
1010FRU BANN MU124.0022.002,728.0010FRU BANN MU12423.002,852.00124.00
1111FRU we3 MU124.0022.002,728.0011FRU we3 MU12422.002,728.000.00
12GAIN31,382.00
STOCK
Cell Formulas
RangeFormula
K11K11=I11*J11
L11L11=K11-E11
L12L12=SUM(L$2:L11)
 
Upvote 0
Can we see the QW sheet that was used to come up with those last "right" results?
this is not existed in QW sheet
sub.xlsm
JKLMN
1ITEMBATCH01/11/202402/11/202403/11/2024
21APP PP FRUIT12.0011.0011.00
32BAN FF FRUIT9.00
43CU CMC VEG11.0011.0011.00
54FRU BANN MU22.0045.00
65PI PIA FRUIT21.0021.0021.00
76PO PTT VEG12.0011.0011.00
87TO TMA VEG5.004.0033.00
98TE TEE FOOD23.0018.0018.00
109TRB POT BNG22.0024.0024.00
1110TRB AAT tt23.0024.0024.00
QW
 
Upvote 0
Change
Code:
    s(0) = "Select A.`ITEM`, A.`BATCH`, A.`QTY`, B.`UP` As `UNIT PRICE`, " & _
        "A.`QTY` * B.`UP` As `TOTAL`, A.`QTY` * B.`UP` - A.`TOTAL` As `D/P` " & _
        "From `STOCK$` As A Left Join `QW$` As B On A.`BATCH` = B.`BATCH`;"
to
Code:
    s(0) = "Select A.`ITEM`, A.`BATCH`, A.`QTY`, IIf(IsNull(B.`UP`), A.`UNIT PRICE`, B.`UP`) As `UNIT PRICE`, " & _
        "IIf(IsNull(B.`UP`), A.`TOTAL`, A.`QTY` * B.`UP`) As `TOTAL`, A.`QTY` * B.`UP` - A.`TOTAL` As `D/P` " & _
        "From `STOCK$` As A Left Join `QW$` As B On A.`BATCH` = B.`BATCH`;"
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,175
Members
453,021
Latest member
Justyna P

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