Extract 4 digit year from inconsistent string of text

kirksmim

New Member
Joined
May 6, 2016
Messages
12
First posting here so apologies for anything I miss out.

I work in an academic library and I'm trying to profile the collection by year published. The only problem is that the dates for academic journals (which span several years) are inputted manually and therefore are written in an infinite amount of different formats.

Below I have posted an example of the types of dates.

While this is obviously a mess, the reason I retain some hope is that the only 4-digit numbers are years, so if I could somehow extract these it would give me a fighting chance.


Start date Summary Description
N1-VOL.5, 1949-1953. N1-VOL.5, 1949-1953.
1996 VOL.1 NO.1 (1996)-Vol. 8 No. 1 (2003) VOL.1 NO.1 (1996)-
1955-1977. 1955-1977.
2010 VOL.398 (2010)- Vol. 412, No. 8896 (2014 Jul. 19)
2010 VOL.398 (2010)- Vol. 412, No. 8897 (2014 Jul. 26)

In summary: does anyone know a query for 'extract 4-digit numbers from string of text and numbers'? If not has anyone got any idea how else I can solve this?

Many thanks,
Michael
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Start date Summary Description
N1-VOL.5, 1949-1953. N1-VOL.5, 1949-1953.
1996 VOL.1 NO.1 (1996)-Vol. 8 No. 1 (2003) VOL.1 NO.1 (1996)-
1955-1977. 1955-1977.
2010 VOL.398 (2010)- Vol. 412, No. 8896 (2014 Jul. 19)
2010 VOL.398 (2010)- Vol. 412, No. 8897 (2014 Jul. 26)
 
Upvote 0

Cell Formulas
RangeFormula
P29999
P39999
P49999
P59999
P69999
Q2N1-VOL.5, 1949-1953.
Q3VOL.1 NO.1 (1996)-Vol. 8 No. 1 (2003)
Q41955-1977.
Q5VOL.398 (2010)-
Q6VOL.398 (2010)-
R2N1-VOL.5, 1949-1953.
R3VOL.1 NO.1 (1996)-
R41955-1977.
R5Vol. 412, No. 8896 (2014 Jul. 19)
R6Vol. 412, No. 8897 (2014 Jul. 26)
O31996
O52010
O62010
 
Upvote 0
This is a classic "select case" opportunity for vba code. This means getting under the hood of Excel and writing a very clever bit of code that does this for you. The brilliant thing about using "select case" is that you can always add more varieties without expanding a formula to complex and frankly, unmanageable scales.

My recommendation for your request is that you learn about macros and Excel VBA coding first. It makes the whole process if collecting and storing data easier and you can manipulate the data far better with code than formulae.

The best bit is that once you've done the hard work, updates to it are simple and usually improve the code.
 
Upvote 0
I'm quite pleased with this :)

Assumes the following:
Data in column A
Output in column B

Runs down column A, searches each cell, extracts all values where four digits are next to each other

Code:
Sub extractyears()
lastrow = Worksheets("Sheet1").Cells(Rows.Count, "A").End(xlUp).Row
For m = 1 To lastrow
n = Cells(m, 1)
l = ""
For i = 1 To Len(n) - 3
k = 0
For j = 1 To 4
If Mid(n, (i - 1) + j, 1) >= "0" And Mid(n, (i - 1) + j, 1) <= "9" Then
k = k + 1
End If
Next j
If k = 4 Then
l = l & Mid(n, i, 4) & " "
End If
Next i
Cells(m, 2) = l
Next m
End Sub
 
Last edited:
Upvote 0
And so you should be!

That worked perfectly thanks very much.

I feel this is only this in only the first of many hurdles I'll come across with this data but I am very grateful for your help with getting me over this one!
 
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,915
Members
448,532
Latest member
9Kimo3

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