count the duplicate entries with the help of Macro

chirag_patel5141

New Member
Joined
Jun 4, 2016
Messages
10
Hi All,
I want to Count the Duplicate entries in the column "SYMBOL" with the refeance of column "EXPIRY_DT" and also want to number them like...
IF 31-Mar-16 than BANKNIFTY-I , 28-Apr-16 than BANKNIFTY-II & 26-MAY-16 than BANKNIFTY-III


[TABLE="width: 664"]
<tbody>[TR]
[TD]INSTRUMENT[/TD]
[TD]"SYMBOL"[/TD]
[TD]"EXPIRY_DT"[/TD]
[TD]OPEN[/TD]
[TD]HIGH[/TD]
[TD]LOW[/TD]
[TD]CLOSE[/TD]
[TD]OPEN_INT[/TD]
[TD]CHG_IN_OI"[/TD]
[TD]TIMESTAMP"[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]BANKNIFTY[/TD]
[TD="align: right"]31-Mar-16[/TD]
[TD="align: right"]15745[/TD]
[TD="align: right"]15965.7[/TD]
[TD="align: right"]15740[/TD]
[TD="align: right"]15941.55[/TD]
[TD="align: right"]2350350[/TD]
[TD="align: right"]194280[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]BANKNIFTY[/TD]
[TD="align: right"]28-Apr-16[/TD]
[TD="align: right"]15816[/TD]
[TD="align: right"]16036[/TD]
[TD="align: right"]15816[/TD]
[TD="align: right"]16017.55[/TD]
[TD="align: right"]294210[/TD]
[TD="align: right"]23010[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]BANKNIFTY[/TD]
[TD="align: right"]26-May-16[/TD]
[TD="align: right"]15876.1[/TD]
[TD="align: right"]16049.95[/TD]
[TD="align: right"]15850[/TD]
[TD="align: right"]16042.95[/TD]
[TD="align: right"]104490[/TD]
[TD="align: right"]840[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]13-Apr-16[/TD]
[TD="align: right"]17460[/TD]
[TD="align: right"]17512.5[/TD]
[TD="align: right"]17440[/TD]
[TD="align: right"]17507.5[/TD]
[TD="align: right"]16950[/TD]
[TD="align: right"]3060[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]20-May-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]16740[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]17-Jun-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]16385[/TD]
[TD="align: right"]30[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]16-Sep-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]16702.5[/TD]
[TD="align: right"]30[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]16-Dec-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]18835[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]DJIA[/TD]
[TD="align: right"]17-Mar-17[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]18965[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]13-Apr-16[/TD]
[TD="align: right"]6398[/TD]
[TD="align: right"]6398[/TD]
[TD="align: right"]6398[/TD]
[TD="align: right"]6398[/TD]
[TD="align: right"]75[/TD]
[TD="align: right"]75[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]20-May-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]6091[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]17-Jun-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]7242[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]16-Sep-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]6637[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]16-Dec-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]6570[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]FTSE100[/TD]
[TD="align: right"]17-Mar-17[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]6728[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTY[/TD]
[TD="align: right"]31-Mar-16[/TD]
[TD="align: right"]7623.5[/TD]
[TD="align: right"]7723.2[/TD]
[TD="align: right"]7615.2[/TD]
[TD="align: right"]7713.35[/TD]
[TD="align: right"]21508425[/TD]
[TD="align: right"]-751800[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTY[/TD]
[TD="align: right"]28-Apr-16[/TD]
[TD="align: right"]7664.9[/TD]
[TD="align: right"]7761.4[/TD]
[TD="align: right"]7658.4[/TD]
[TD="align: right"]7750.8[/TD]
[TD="align: right"]4290900[/TD]
[TD="align: right"]391575[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTY[/TD]
[TD="align: right"]26-May-16[/TD]
[TD="align: right"]7677.45[/TD]
[TD="align: right"]7773.4[/TD]
[TD="align: right"]7672.15[/TD]
[TD="align: right"]7763.7[/TD]
[TD="align: right"]1075425[/TD]
[TD="align: right"]77775[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTYINFRA[/TD]
[TD="align: right"]31-Mar-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2565[/TD]
[TD="align: right"]150[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTYINFRA[/TD]
[TD="align: right"]28-Apr-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2440.95[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
[TR]
[TD]FUTIDX[/TD]
[TD]NIFTYINFRA[/TD]
[TD="align: right"]26-May-16[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2330.45[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]21-Mar-16[/TD]
[/TR]
</tbody>[/TABLE]
 
In above example If Symbol of BANKNIFTY comes with any other EXPIRY_DT (date), for example 29-Sep-16 than the New Symbol will be BANKNIFTY-IV ..
 
Upvote 0

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG06Jun39
[COLOR="Navy"]Dim[/COLOR] Dn      [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Rng     [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dic     [COLOR="Navy"]As[/COLOR] Object
[COLOR="Navy"]Dim[/COLOR] k       [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] p       [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] c       [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
 
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("B2"), Range("B" & Rows.Count).End(xlUp))
 [COLOR="Navy"]Set[/COLOR] Dic = CreateObject("Scripting.Dictionary")
    Dic.CompareMode = 1
   [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
            [COLOR="Navy"]If[/COLOR] Not Dic.exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
                [COLOR="Navy"]Set[/COLOR] Dic(Dn.Value) = CreateObject("Scripting.Dictionary")
            [COLOR="Navy"]End[/COLOR] If
        
        [COLOR="Navy"]If[/COLOR] Not Dic(Dn.Value).exists(Dn.Offset(, 1).Value) [COLOR="Navy"]Then[/COLOR]
                Dic(Dn.Value).Add (Dn.Offset(, 1).Value), Dn
        [COLOR="Navy"]Else[/COLOR]
                [COLOR="Navy"]Set[/COLOR] Dic(Dn.Value).Item(Dn.Offset(, 1).Value) = _
                Union(Dic(Dn.Value).Item(Dn.Offset(, 1).Value), Dn)
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] k [COLOR="Navy"]In[/COLOR] Dic.Keys
       c = 0
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] p [COLOR="Navy"]In[/COLOR] Dic(k)
        c = c + 1
         [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Dic(k).Item(p)
           Dn.Value = Dn.Value & "-" & WorksheetFunction.Roman(c)
         [COLOR="Navy"]Next[/COLOR] Dn
    [COLOR="Navy"]Next[/COLOR] p
[COLOR="Navy"]Next[/COLOR] k
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,223,229
Messages
6,170,881
Members
452,364
Latest member
springate

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