SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2008 Forums
 SSIS and Import/Export (2008)
 Which SSIS 2008R2 BIDS transform(s) to use?
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

hmbrraymond
Starting Member

1 Posts

Posted - 07/19/2013 :  15:05:35  Show Profile  Reply with Quote
Which SSIS 2008R2 BIDS transform(s)are appropriate to create multiple destination inserts based on prior Fact table entry?

I don't know whether to use some combination of data flow transformations or resort instead to a Script Component to accomplish my goal. I am receiving electric usage odometer-type meter readings, anywhere from 0 to many per day for a given meter. Granularity of Fact table flattens that out to 1 reading per meter per day. So, today's odometer reading comes in and the calculated consumption is done by subtracting the most recent reading for this meter in the fact table from today's odometer value. E.g. last time I got a reading it was 132 and now the meter says 150 so consumption between the readings is 18. To complicate further, if for example 6 days have passed since that last reading I need to insert 1 reading for each day to the Fact table and spread that 18 value across them. So, question is which transforms are most appropriate for having to look into the Fact table's recent past in order to determine record(s) to introduce to the destination pipeline?

Example on Fact table:

Date: 7/10/2013 Meter: MeterA Consumption: 5 Estimated? N LastGoodReading: 132

--------------------------------------------------------

Six days later, on 7/16/2013, MeterA reports a reading for 150. From that I should create following output by using the earlier row, the last reading and the time that has elapsed between readings:

--------------------------------------------------------

Date: 7/11/2013 Meter: MeterA Consumption: 3 Estimated? Y LastGoodReading: NULL

Date: 7/12/2013 Meter: MeterA Consumption: 3 Estimated? Y LastGoodReading: NULL

Date: 7/13/2013 Meter: MeterA Consumption: 3 Estimated? Y LastGoodReading: NULL

Date: 7/14/2013 Meter: MeterA Consumption: 3 Estimated? Y LastGoodReading: NULL

Date: 7/15/2013 Meter: MeterA Consumption: 3 Estimated? Y LastGoodReading: NULL

Date: 7/16/2013 Meter: MeterA Consumption: 3 Estimated? N LastGoodReading: 150

visakh16
Very Important crosS Applying yaK Herder

India
52317 Posts

Posted - 07/20/2013 :  08:27:04  Show Profile  Reply with Quote
easiest way to do this is to use t-sql script with a cross join logic to number table to generate the intermediate rows.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

kingroon
Starting Member

United Kingdom
29 Posts

Posted - 03/26/2014 :  11:05:26  Show Profile  Reply with Quote
quote:
easiest way to do this is to use t-sql script with a cross join logic to number table to generate the intermediate rows.


Had a go at this bit..


begin tran

	set nocount on

	-- setup
	declare @MeterData table ( ReadingDate datetime, MeterName varchar(20), ConsumptionID int, EstimatedData varchar(2), LastGoodReading INT  )
	insert into @MeterData ( ReadingDate, MeterName, ConsumptionID, EstimatedData, LastGoodReading )
		select '7/10/2013', 'MeterA', 3, 'N',  132 
	union select '7/11/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/12/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/13/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/14/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/15/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/16/2013', 'MeterA', 3, 'N',  150
	union select '7/17/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/18/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/19/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/20/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/21/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/22/2013', 'MeterA', 3, 'N',  210
	union select '7/23/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/24/2013', 'MeterA', 3, 'Y',  NULL 
	union select '7/25/2013', 'MeterA', 3, 'N',  260

	-- declarations
	declare @StartDate datetime, @ThisDate datetime, @EndDate datetime, @NextGoodDate datetime, @NextBadDate datetime
	declare @EstimatedCount int, @GoodReading int, @NextGoodReading int, @DaysDifference int, @ReadingDifference int, @NextDay int
	select @StartDate = MIN(ReadingDate) from @MeterData
	select @EndDate = MAX(ReadingDate) from @MeterData
	set @EstimatedCount = 0
	set @NextDay = 1

	-- loop through each row
	while @StartDate <= @EndDate
	begin
		set @ThisDate = @StartDate
		-- first loop, get first Non Estimated Reading
		if ( select EstimatedData from @MeterData where ReadingDate = @ThisDate ) = 'N'
		begin
			select @GoodReading = LastGoodReading from @MeterData where ReadingDate = @ThisDate
			-- get the next good date
			select @NextGoodDate = min(ReadingDate) from @MeterData where ReadingDate > @ThisDate and EstimatedData = 'N'
			select @NextGoodReading = LastGoodReading from @MeterData where ReadingDate = @NextGoodDate
			select @DaysDifference = datediff(day, @ThisDate, @NextGoodDate)
			
			-- calculate
			set @ReadingDifference = (@NextGoodReading - @GoodReading) / @DaysDifference
			set @NextBadDate = dateadd(day, 1, @ThisDate)
			
			while @NextBadDate < @NextGoodDate
			begin
				-- update NULL values
				update @MeterData
				set LastGoodReading = @GoodReading + (@ReadingDifference * @NextDay)
				where ReadingDate = @NextBadDate
					and EstimatedData = 'Y'

				-- iterate
				set @NextDay = @NextDay + 1
				set @NextBadDate = @NextBadDate + 1
			end
			-- reset variables
			set @ReadingDifference = 0;
			set @NextGoodReading = 0;
			set @NextDay = 1;
		end
		-- move to the next day
		set @StartDate = dateadd(day, 1, @StartDate)
	end

	select * from @MeterData

rollback


Outout:
ReadingDate			MeterName	ConsumptionID	EstimatedData	LastGoodReading
2013-07-10 00:00:00.000	MeterA		3			N			132
2013-07-11 00:00:00.000	MeterA		3			Y			135
2013-07-12 00:00:00.000	MeterA		3			Y			138
2013-07-13 00:00:00.000	MeterA		3			Y			141
2013-07-14 00:00:00.000	MeterA		3			Y			144
2013-07-15 00:00:00.000	MeterA		3			Y			147
2013-07-16 00:00:00.000	MeterA		3			N			150
2013-07-17 00:00:00.000	MeterA		3			Y			160
2013-07-18 00:00:00.000	MeterA		3			Y			170
2013-07-19 00:00:00.000	MeterA		3			Y			180
2013-07-20 00:00:00.000	MeterA		3			Y			190
2013-07-21 00:00:00.000	MeterA		3			Y			200
2013-07-22 00:00:00.000	MeterA		3			N			210
2013-07-23 00:00:00.000	MeterA		3			Y			226
2013-07-24 00:00:00.000	MeterA		3			Y			242
2013-07-25 00:00:00.000	MeterA		3			N			260


Hasta Luego..
KingRoon

http://www.dogfightclothing.com

Edited by - kingroon on 03/26/2014 11:09:20
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.05 seconds. Powered By: Snitz Forums 2000