Forum Discussion

Pat_Burrows1970's avatar
Pat_Burrows1970
Copper Contributor
Oct 04, 2022

Stamp Duty Calculation

Hello,

 

I have a SUMPRODUCT formula to calculate stamp duty in the UK below where F2 = the purchase price of a property. 

 

=SUMPRODUCT(--(F2>{0;250000;925000;1500000}),(F2-{0;250000;925000;1500000}), {0.03;0.05;0.05;0.02})

 

I want to edit this formula so that if F2 is less than 40000 then the stamp duty = £0 regardless of the above formula.

 

Can anyone assist me please?

 

Thanks,

 

Pat

 

  • Pat_Burrows1970 

    =IF(F2<40000,0,SUMPRODUCT(--(F2>{0;250000;925000;1500000}),(F2-{0;250000;925000;1500000}),{0.03;0.05;0.05;0.02}))

     

    Does this return the expected result?

  • Pat_Burrows1970 

    =IF(F2<40000,0,SUMPRODUCT(--(F2>{0;250000;925000;1500000}),(F2-{0;250000;925000;1500000}),{0.03;0.05;0.05;0.02}))

     

    Does this return the expected result?

    • andysw90's avatar
      andysw90
      Copper Contributor

      OliverScheurich 

       

      If anyone comes across this thread more recently, rates have now changed...

      =IF(B4<40000,0,SUMPRODUCT(--(B4>{0;250000;925000;1500000}),(B4-{0;250000;925000;1500000}),{0;0.05;0.1;0.12}))

       

      • Umairzh's avatar
        Umairzh
        Copper Contributor

        andysw90 

         

        The correct formula incorporating rates as of March 2024 is as follows;

        =SUMPRODUCT(--(F8>{0;250000;925000;1500000}),(F8-{0;250000;925000;1500000}),({0;0.05;0.05;0.07}))

         

        Note, the rates are incremental so for although its 10% SDLT from £925k to £1.5m, we have to use 5% increment over the previous tier.

Resources