VBA - return value in different columns upon a criteria

mogri

New Member
Joined
Jul 25, 2019
Messages
3
Hi all,

I would like to have the excel show the net income for each type of day as attached.

CDEFGHIJ
Expense_WeekdayExpense_WeekendExpense_HolidayIncomeNet_WeekdayNet_WeekendNet_HolidayDay
492600108Sat
480750270Mon
300230-70Holiday

<tbody>
</tbody>

The formula is same for all calculation = Column"F" - Column"C" - Column"D"- Column"E" where

The value will be returned in a different column like, if the value in column "J " is Mon,Tue,Wed,Thu or Fri, the value will return in column "G", if the value in column "J" is Sat or Sun, the value will return in column "H" and if the value in column "J" is other, the value will be returned in Column "I".

I have tried tweaking the code found as below yet it still doesn't work. Can anyone help me know where I should modify more to make the code work? Also, can anyone give me any hint what should I write for the case of holiday as it is any word other than the words in Weekday and Weekend?

---------------------------------------------------------------------
Sub Calculate()


Dim LR As Long
Dim i As Long
Dim j As Long
Dim Weekday As Variant
Dim Weekend As Variant


Weekday = Array("Mon", "Tue", "Wed", "Thu", "Fri")
Weekend = Array("Sat", "Sun")
LR = Range("J3:J" & Rows.Count).End(xlUp).Row


For i = 1 To LR

With Range("J3:J" & i)
For j = LBound(Weekday) To UBound(Weekday)
If Cell.Value Like "*" & Weekday(j) & "*" Then
Cell.Offset(0, -3).Value = Cell.Offset(0, -4).Value - Cell.Offset(0, -5).Value - Cell.Offset(0, -6).Value - Cell.Offset(0, -7).Value
Exit For
End If
Next j

For j = LBound(Weekend) To UBound(Weekend)
If .Value Like "*" & Weekend(j) & "*" Then
Cell.Offset(0, -2).Value = Cell.Offset(0, -4).Value - Cell.Offset(0, -5).Value - Cell.Offset(0, -6).Value - Cell.Offset(0, -7).Value
Exit For
End If
Next j
End With
Next


End Sub
---------------------------------------------------------------------
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Try this:-
NB:- It look like you first 2 values in columns "C & D" are in the wrong columns ??
Code:
[COLOR="Navy"]Sub[/COLOR] MG25Jul44
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range("J2", Range("J" & Rows.Count).End(xlUp))
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
    [COLOR="Navy"]For[/COLOR] ac = -7 To -5
        [COLOR="Navy"]If[/COLOR] Dn.Offset(, ac) <> "" [COLOR="Navy"]Then[/COLOR]
            Dn.Offset(, ac + 4).Value = Dn.Offset(, -4).Value - Dn.Offset(, ac).Value
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] ac
[COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Oh, yes...you are correct. The 2 values are in the wrong column. Sorry for the confusion.

Your code really wows me. It exactly gets the answer I had been working for hours without using the condition on the day, and above all it's really short.

Thanks a lot!
 
Upvote 0
If cells from C to D are evaluated, it could also be

Code:
Sub DAM_Return_Value()
    With Range("G3:I" & Range("J" & Rows.Count).End(xlUp).Row)
      .FormulaR1C1 = "=IF(RC[-4]="""","""",RC6-RC[-4])"
      .Value = .Value
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,013
Messages
6,122,694
Members
449,092
Latest member
snoom82

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