Automatic Dataset Cleaning for Blanks

karlitob

New Member
Joined
Jun 24, 2017
Messages
38
Would appreciate some help please.

I have quite a large dataset that gets updated on a monthly basis (100,000 rows +). There are 4 unique provinces each 10 unique counties in each province. The users that enter data into the form - using drop down boxes - that generates these fields (among others) is not mandatory. Users should enter the province and county on the form but oft times omit the province. While I'm working with the people who make these fields mandatory there are a lot of blanks in my table. So I manually clean up the data. Could anyone advise on a way to clean the blanks up automatically.

Province1: County1, Country2,..., County10
Province2: County11, County12,..., County20
Province3: County21, County22,..., County30
Province4: County31, County32,..., County40



Province 1: County1
Province 4: County31
Blank: County11
Blank: County40

- Since all the counties are unique, and there are only 40, I know that for County11, the Province is Province2.


Hope that all makes sense. Thanks all. Appreciate any guidance.
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Hi,

You can prepare a column with a list of all provinces and against all of them llist to the respective countries...

In my sample :

Column D contain the list of all provinces and columns E1:H6 contains respective the list of all countries
Column B contain the list of countries (Enter by users)


An array formula - Ctrl+Shift+Enter NOT just Enter

A1 =INDEX($D$1:$D$6,MATCH(1,MMULT(--($E$1:$H$6=B1),TRANSPOSE(COLUMN($E$1:$H$6)^0)),0))


[TABLE="width: 679"]
<colgroup><col><col><col><col><col><col span="4"></colgroup><tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[TD]E[/TD]
[TD]F[/TD]
[TD]G[/TD]
[TD]H[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]Province 5: [/TD]
[TD]Country33[/TD]
[TD][/TD]
[TD]Province 1: [/TD]
[TD]Country1[/TD]
[TD]Country14[/TD]
[TD]Country24[/TD]
[TD]Country34[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Province 1: [/TD]
[TD]Country24[/TD]
[TD][/TD]
[TD]Province 2: [/TD]
[TD]Country31[/TD]
[TD]Country40[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]Province 3: [/TD]
[TD]Country5[/TD]
[TD][/TD]
[TD]Province 3: [/TD]
[TD]Country11[/TD]
[TD]Country10[/TD]
[TD]Country5[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]Province 2: [/TD]
[TD]Country40[/TD]
[TD][/TD]
[TD]Province 4: [/TD]
[TD]Country6[/TD]
[TD]Country15[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]Province 6: [/TD]
[TD]Country19[/TD]
[TD][/TD]
[TD]Province 5: [/TD]
[TD]Country2[/TD]
[TD]Country33[/TD]
[TD]Country9[/TD]
[TD]Country8[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Province 6: [/TD]
[TD]Country19[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,195
Members
453,021
Latest member
pingpong7117

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