May 18, 2011 at 5:34 pm
Is there a way to find all of the patterns that exist for data entered in a field?
I have an PO_NUM column that is supposed to have data in the following pattern: dd-dddd
However, people were allowed to enter anything in the field, so there is a lot of data in the field that does not conform to that pattern.
I need a way to identify all of the different patterns that exist in the data. Can anyone help?
Thanks!
May 18, 2011 at 5:47 pm
That is quite a difficult one to answer because we don't know what you consider to be a pattern.
It looks like you are using "d" to indicate a numeric digit, so perhaps you want to know what patterns of digits there are?
If so, you could do something like this:
;with data(col) as
(
SELECT '12-222' union all
SELECT '12222' union all
SELECT '12-2222' union all
SELECT '1-222' union all
SELECT '32-444' union all
SELECT '52162' union all
SELECT '12-2222' union all
SELECT '123-222'
)
select pattern,COUNT(*) as occurrences
from data
cross apply (
select pattern =
replace(
replace(
replace(
replace(
replace(
replace(
replace(
replace(
replace(
replace(col ,'0','d')
,'1','d')
,'2','d')
,'3','d')
,'4','d')
,'5','d')
,'6','d')
,'7','d')
,'8','d')
,'9','d')
) AS anything
group by pattern
Results:
patternoccurrences
d-ddd1
ddddd2
dd-ddd2
dd-dddd2
ddd-ddd1
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
Viewing 2 posts - 1 through 1 (of 1 total)
You must be logged in to reply to this topic. Login to reply