October 24, 2014 at 11:55 am
Hi Guys,
Need help in SSIS.
Here is source looks like
Sample Source Data .xlxs file
Add, New, Pro, Len, Source
Acorn,Null,Null,Null,Null
Null,FC,Null,Null,Null
Null,Null,Day,Null,Null
Null,Null,Null,2:00,Null
Null,Null,Null,Null,Phone
Null,Null,Null,Null,Web
Boster,Null,Null,Null,Null
Null,LC,Null,Null,Null
Null,Null,Night,Null,Null
Null,Null,Null,1:00,Null
Null,Null,Null,Null,Phone
Null,Null,Null,Null,Web
Here what I want Two Files from above One File
File One
Add, New, Pro, Len, Source
Acorn,FC,Day,2:00,Phone
Acron,FC,Day,2:00,Web
File Second
Add, New, Pro, Len, Source
Boster,LC,Night,1:00,Phone
Boster,LC,Night,1:00,Web
Please any advise would be great appreciate.
Thank You.
October 24, 2014 at 11:57 am
In the Dataflow, use a multi-cast transformation. Then, define the two destinations and select the columns you want.
Gerald Britton, Pluralsight courses
October 24, 2014 at 12:11 pm
Thanks for your help, got it I can use multicast for different file, how about ?
Source:-
Add, New, Pro, Len, Source
Acorn,Null,Null,Null,Null
Null,FC,Null,Null,Null
Null,Null,Day,Null,Null
Null,Null,Null,2:00,Null
Null,Null,Null,Null,Phone
Null,Null,Null,Null,Web
Destination File:-
Add, New, Pro, Len, Source
Acorn,FC,Day,2:00,Phone
Acron,FC,Day,2:00,Web
this format ?
October 24, 2014 at 2:42 pm
Sure. Try it!
Gerald Britton, Pluralsight courses
October 24, 2014 at 6:29 pm
rocky_498 (10/24/2014)
Thanks for your help, got it I can use multicast for different file, how about ?Source:-
Add, New, Pro, Len, Source
Acorn,Null,Null,Null,Null
Null,FC,Null,Null,Null
Null,Null,Day,Null,Null
Null,Null,Null,2:00,Null
Null,Null,Null,Null,Phone
Null,Null,Null,Null,Web
Destination File:-
Add, New, Pro, Len, Source
Acorn,FC,Day,2:00,Phone
Acron,FC,Day,2:00,Web
this format ?
To be honest, this is death by SQL because there is nothing in any of the rows to associate the correct rows with each other. Also, the "angular" nature of the data is typically caused by someone using an EAV as a source and not having a clue on how to do a proper CROSS TAB or PIVOT>
My recommendation would be to save yourself a whole lot of future heartache and tell the folks that are providing the data that there format is NOT acceptable especially from a data integrity stand point and that they REALLY need to spend 10 minutes learning how to create this simple output correctly.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 24, 2014 at 10:06 pm
Thanks for reply. I wish I can ask my client to provide different file. Is there any I can get the output that I need? through t-sql or SSIS?
Thank You.
October 25, 2014 at 2:15 am
To get the desired output requires some data massaging, here is an example
😎
USE tempdb;
GO
SET NOCOUNT ON;
;WITH SAMPLE_DATA([Add], [New], [Pro], [Len], [Source]) AS
(
SELECT 'Acorn', Null, Null, Null, Null UNION ALL
SELECT Null, 'FC', Null, Null, Null UNION ALL
SELECT Null, Null, 'Day', Null, Null UNION ALL
SELECT Null, Null, Null, '2:00', Null UNION ALL
SELECT Null, Null, Null, Null, 'Phone' UNION ALL
SELECT Null, Null, Null, Null, 'Web' UNION ALL
SELECT 'Boster',Null, Null, Null, Null UNION ALL
SELECT Null, 'LC', Null, Null, Null UNION ALL
SELECT Null, Null, 'Night',Null, Null UNION ALL
SELECT Null, Null, Null, '1:00', Null UNION ALL
SELECT Null, Null, Null, Null, 'Phone' UNION ALL
SELECT Null, Null, Null, Null, 'Web'
)
,ORDERED_SET AS
(
SELECT
SD.[Add] AS SD_Add
,ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS SD_RID
,SD.[New] AS SD_New
,SD.[Pro] AS SD_Pro
,SD.[Len] AS SD_Len
,SD.[Source] AS SD_Source
FROM SAMPLE_DATA SD
)
,GROUPS_IN_SET AS
(
SELECT
OS.SD_Add
,ROW_NUMBER() OVER (ORDER BY OS.SD_RID) AS GR_RID
,OS.SD_RID
FROM ORDERED_SET OS
WHERE OS.SD_Add IS NOT NULL
)
,MARKED_GROUPS AS
(
SELECT
GIS.SD_Add AS GROUP_NAME
,GIS.GR_RID AS GROUP_NUMBER
,GIS.SD_RID AS GROUP_START
,ISNULL(GTO.SD_RID - 1,(SELECT MAX(SD_RID) FROM ORDERED_SET)) AS GROUP_END
FROM GROUPS_IN_SET GIS
LEFT OUTER JOIN GROUPS_IN_SET GTO
ON GIS.GR_RID = GTO.GR_RID -1
)
,SUB_GROUPS AS
(
SELECT
MG.GROUP_NAME
,OS.SD_Source
FROM ORDERED_SET OS
CROSS JOIN MARKED_GROUPS MG
WHERE OS.SD_RID BETWEEN MG.GROUP_START AND MG.GROUP_END
AND OS.SD_Source IS NOT NULL
)
SELECT
MG.GROUP_NAME
,MG.GROUP_NUMBER
,SG.SD_Source
,MAX(OS.SD_New ) AS SD_New
,MAX(OS.SD_Pro ) AS SD_Pro
,MAX(OS.SD_Len ) AS SD_Len
FROM ORDERED_SET OS
CROSS JOIN MARKED_GROUPS MG
INNER JOIN SUB_GROUPS SG
ON MG.GROUP_NAME = SG.GROUP_NAME
WHERE OS.SD_RID BETWEEN MG.GROUP_START AND MG.GROUP_END
AND OS.SD_Source IS NULL
GROUP BY MG.GROUP_NAME,MG.GROUP_NUMBER,SG.SD_Source;
Results
GROUP_NAME GROUP_NUMBER SD_Source SD_New SD_Pro SD_Len
---------- -------------------- --------- ------ ------ ------
Acorn 1 Phone FC Day 2:00
Acorn 1 Web FC Day 2:00
Boster 2 Phone LC Night 1:00
Boster 2 Web LC Night 1:00
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply