From 279d8ab26374d3e5f477d21e6d549d21b35f67b0 Mon Sep 17 00:00:00 2001 From: David Bures Date: Tue, 3 May 2016 13:59:54 +0200 Subject: [PATCH 1/2] default value for 'Deleted' columns --- src/SQLDatabase/MyDrivingDB.sql | 33 +++++++++++++++++++++++++++++++++ 1 file changed, 33 insertions(+) diff --git a/src/SQLDatabase/MyDrivingDB.sql b/src/SQLDatabase/MyDrivingDB.sql index cffc09bc..6c61112c 100644 --- a/src/SQLDatabase/MyDrivingDB.sql +++ b/src/SQLDatabase/MyDrivingDB.sql @@ -259,6 +259,11 @@ BEGIN ALTER TABLE [dbo].[Devices] ADD DEFAULT (sysutcdatetime()) FOR [CreatedAt] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.Devices')) IS NULL +BEGIN +ALTER TABLE [dbo].[Devices] ADD DEFAULT (0) FOR [Deleted] +END + GO --IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DF__IOTHubDatas__Id__36B12243]') AND type = 'D') IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Id' AND object_id = object_id('dbo.IOTHubDatas')) IS NULL @@ -273,6 +278,11 @@ BEGIN ALTER TABLE [dbo].[IOTHubDatas] ADD DEFAULT (sysutcdatetime()) FOR [CreatedAt] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.IOTHubDatas')) IS NULL +BEGIN +ALTER TABLE [dbo].[IOTHubDatas] ADD DEFAULT (0) FOR [Deleted] +END + GO --IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DF__POIs__Id__3B75D760]') AND type = 'D') IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Id' AND object_id = object_id('dbo.POIs')) IS NULL @@ -294,6 +304,12 @@ BEGIN ALTER TABLE [dbo].[POIs] ADD DEFAULT ('1900-01-01T00:00:00.000') FOR [Timestamp] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.POIs')) IS NULL +BEGIN +ALTER TABLE [dbo].[POIs] ADD DEFAULT (0) FOR [Deleted] +END + + GO --IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DF__TripPoints__Id__403A8C7D]') AND type = 'D') IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Id' AND object_id = object_id('dbo.TripPoints')) IS NULL @@ -308,6 +324,12 @@ BEGIN ALTER TABLE [dbo].[TripPoints] ADD DEFAULT (sysutcdatetime()) FOR [CreatedAt] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.TripPoints')) IS NULL +BEGIN +ALTER TABLE [dbo].[TripPoints] ADD DEFAULT (0) FOR [Deleted] +END + + GO --IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DF__Trips__Id__44FF419A]') AND type = 'D') IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Id' AND object_id = object_id('dbo.Trips')) IS NULL @@ -322,6 +344,11 @@ BEGIN ALTER TABLE [dbo].[Trips] ADD DEFAULT (sysutcdatetime()) FOR [CreatedAt] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.Trips')) IS NULL +BEGIN +ALTER TABLE [dbo].[Trips] ADD DEFAULT (0) FOR [Deleted] +END + GO --IF NOT EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[DF__UserProfiles__Id__49C3F6B7]') AND type = 'D') IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Id' AND object_id = object_id('dbo.UserProfiles')) IS NULL @@ -336,6 +363,12 @@ BEGIN ALTER TABLE [dbo].[UserProfiles] ADD DEFAULT (sysutcdatetime()) FOR [CreatedAt] END +IF (SELECT object_definition(default_object_id) AS definition FROM sys.columns WHERE name ='Deleted' AND object_id = object_id('dbo.UserProfiles')) IS NULL +BEGIN +ALTER TABLE [dbo].[UserProfiles] ADD DEFAULT (0) FOR [Deleted] +END + + GO IF NOT EXISTS (SELECT * FROM sys.foreign_keys WHERE object_id = OBJECT_ID(N'[dbo].[FK_dbo.Devices_dbo.UserProfiles_UserProfile_Id]') AND parent_object_id = OBJECT_ID(N'[dbo].[Devices]')) ALTER TABLE [dbo].[Devices] WITH CHECK ADD CONSTRAINT [FK_dbo.Devices_dbo.UserProfiles_UserProfile_Id] FOREIGN KEY([UserProfile_Id]) From 20e7a7b60a4cb1d29e5b55eae52190f14a3f528a Mon Sep 17 00:00:00 2001 From: David Bures Date: Tue, 3 May 2016 14:42:16 +0200 Subject: [PATCH 2/2] updated TripPointRaw - it is used for AVG/MIN/MAX later in script, it means -255 (non exisiting) values need to be replaced by NULLs removed not used value "TripDataPoint.RelativeThrottlePosition as throttle" because both - RelativeThrottlePosition and ThrottlePosition are already there and used --- src/StreamAnalytics/asa_hourlypbi_query.txt | 77 ++++++++++++++----- .../asa_sqlsink_powerbisink_query.txt | 77 ++++++++++++++----- 2 files changed, 118 insertions(+), 36 deletions(-) diff --git a/src/StreamAnalytics/asa_hourlypbi_query.txt b/src/StreamAnalytics/asa_hourlypbi_query.txt index d5a2c77f..ceffe5d5 100644 --- a/src/StreamAnalytics/asa_hourlypbi_query.txt +++ b/src/StreamAnalytics/asa_hourlypbi_query.txt @@ -1,27 +1,68 @@ WITH TripPointRaw as ( SELECT - TripId, + TripId, UserId, - TripDataPoint.Lat as RawLat, - TripDataPoint.Lon as RawLong, - CAST(TripDataPoint.Speed as FLOAT) as spd, - CAST(TripDataPoint.EngineRPM as FLOAT) as enginerpm, - CAST(TripDataPoint.EngineLoad as FLOAT) as engineLoad, - CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) as shortTermFuelBank, - CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) as longTermFuelBank, - CAST(TripDataPoint.MAFFlowRate as FLOAT) as flowRate, - CAST(TripDataPoint.ThrottlePosition as FLOAT) as throttlePos, - CAST(TripDataPoint.Runtime as FLOAT) as runtime, - CAST(TripDataPoint.DistanceWithMIL as FLOAT) as distanceWithMIL, - CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) as relativeThrottlePos, - CAST(TripDataPoint.OutsideTemperature as FLOAT) as outsideTemperature, - CAST(TripDataPoint.EngineFuelRate as FLOAT) as engineFuelRate, + CASE + WHEN CAST(TripDataPoint.Lat as FLOAT) != 255 THEN CAST(TripDataPoint.Lat as FLOAT) + ELSE NULL + END as RawLat, + CASE + WHEN CAST(TripDataPoint.Lon as FLOAT) != 255 THEN CAST(TripDataPoint.Lon as FLOAT) + ELSE NULL + END as RawLong, + CASE + WHEN CAST(TripDataPoint.Speed as FLOAT) >=0 THEN CAST(TripDataPoint.Speed as FLOAT) + ELSE NULL + END as spd, + CASE + WHEN CAST(TripDataPoint.EngineRPM as FLOAT) != -255 THEN CAST(TripDataPoint.EngineRPM as FLOAT) + ELSE NULL + END as enginerpm, + CASE + WHEN CAST(TripDataPoint.EngineLoad as FLOAT) != -255 THEN CAST(TripDataPoint.EngineLoad as FLOAT) + ELSE NULL + END as engineLoad, + CASE + WHEN CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) != -255 THEN CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) + ELSE NULL + END as shortTermFuelBank, + CASE + WHEN CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) != -255 THEN CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) + ELSE NULL + END as longTermFuelBank, + CASE + WHEN CAST(TripDataPoint.MAFFlowRate as FLOAT) != -255 THEN CAST(TripDataPoint.MAFFlowRate as FLOAT) + ELSE NULL + END as flowRate, + CASE + WHEN CAST(TripDataPoint.ThrottlePosition as FLOAT) != -255 THEN CAST(TripDataPoint.ThrottlePosition as FLOAT) + ELSE NULL + END as throttlePos, + CASE + WHEN CAST(TripDataPoint.Runtime as FLOAT) >=0 THEN CAST(TripDataPoint.Runtime as FLOAT) + ELSE NULL + END as runtime, + CASE + WHEN CAST(TripDataPoint.DistanceWithMIL as FLOAT) >=0 THEN CAST(TripDataPoint.DistanceWithMIL as FLOAT) + ELSE NULL + END as distanceWithMIL, + CASE + WHEN CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) != -255 THEN CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) + ELSE NULL + END as relativeThrottlePos, + CASE + WHEN CAST(TripDataPoint.OutsideTemperature as FLOAT) != -255 THEN CAST(TripDataPoint.OutsideTemperature as FLOAT) + ELSE NULL + END as outsideTemperature, + CASE + WHEN CAST(TripDataPoint.EngineFuelRate as FLOAT) != -255 THEN CAST(TripDataPoint.EngineFuelRate as FLOAT) + ELSE NULL + END as engineFuelRate, + TripDataPoint.VIN as vin, TripDataPoint.RecordedTimeStamp as actualTS, DATEADD(millisecond,- DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp)) as ts, - DATEDIFF(millisecond, TripDataPoint.RecordedTimeStamp, DATEADD(millisecond,-DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp))) as tsDiff, - TripDataPoint.VIN as vin, - TripDataPoint.RelativeThrottlePosition as throttle + DATEDIFF(millisecond, TripDataPoint.RecordedTimeStamp, DATEADD(millisecond,-DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp))) as tsDiff FROM CarDeviceData TIMESTAMP by TripDataPoint.RecordedTimeStamp WHERE diff --git a/src/StreamAnalytics/asa_sqlsink_powerbisink_query.txt b/src/StreamAnalytics/asa_sqlsink_powerbisink_query.txt index fadc61d0..7ffc74f0 100644 --- a/src/StreamAnalytics/asa_sqlsink_powerbisink_query.txt +++ b/src/StreamAnalytics/asa_sqlsink_powerbisink_query.txt @@ -1,27 +1,68 @@ WITH TripPointRaw as ( SELECT - TripId, + TripId, UserId, - TripDataPoint.Lat as RawLat, - TripDataPoint.Lon as RawLong, - CAST(TripDataPoint.Speed as FLOAT) as spd, - CAST(TripDataPoint.EngineRPM as FLOAT) as enginerpm, - CAST(TripDataPoint.EngineLoad as FLOAT) as engineLoad, - CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) as shortTermFuelBank, - CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) as longTermFuelBank, - CAST(TripDataPoint.MAFFlowRate as FLOAT) as flowRate, - CAST(TripDataPoint.ThrottlePosition as FLOAT) as throttlePos, - CAST(TripDataPoint.Runtime as FLOAT) as runtime, - CAST(TripDataPoint.DistanceWithMIL as FLOAT) as distanceWithMIL, - CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) as relativeThrottlePos, - CAST(TripDataPoint.OutsideTemperature as FLOAT) as outsideTemperature, - CAST(TripDataPoint.EngineFuelRate as FLOAT) as engineFuelRate, + CASE + WHEN CAST(TripDataPoint.Lat as FLOAT) != 255 THEN CAST(TripDataPoint.Lat as FLOAT) + ELSE NULL + END as RawLat, + CASE + WHEN CAST(TripDataPoint.Lon as FLOAT) != 255 THEN CAST(TripDataPoint.Lon as FLOAT) + ELSE NULL + END as RawLong, + CASE + WHEN CAST(TripDataPoint.Speed as FLOAT) >=0 THEN CAST(TripDataPoint.Speed as FLOAT) + ELSE NULL + END as spd, + CASE + WHEN CAST(TripDataPoint.EngineRPM as FLOAT) != -255 THEN CAST(TripDataPoint.EngineRPM as FLOAT) + ELSE NULL + END as enginerpm, + CASE + WHEN CAST(TripDataPoint.EngineLoad as FLOAT) != -255 THEN CAST(TripDataPoint.EngineLoad as FLOAT) + ELSE NULL + END as engineLoad, + CASE + WHEN CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) != -255 THEN CAST(TripDataPoint.ShortTermFuelBank1 as FLOAT) + ELSE NULL + END as shortTermFuelBank, + CASE + WHEN CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) != -255 THEN CAST(TripDataPoint.LongTermFuelBank1 as FLOAT) + ELSE NULL + END as longTermFuelBank, + CASE + WHEN CAST(TripDataPoint.MAFFlowRate as FLOAT) != -255 THEN CAST(TripDataPoint.MAFFlowRate as FLOAT) + ELSE NULL + END as flowRate, + CASE + WHEN CAST(TripDataPoint.ThrottlePosition as FLOAT) != -255 THEN CAST(TripDataPoint.ThrottlePosition as FLOAT) + ELSE NULL + END as throttlePos, + CASE + WHEN CAST(TripDataPoint.Runtime as FLOAT) >=0 THEN CAST(TripDataPoint.Runtime as FLOAT) + ELSE NULL + END as runtime, + CASE + WHEN CAST(TripDataPoint.DistanceWithMIL as FLOAT) >=0 THEN CAST(TripDataPoint.DistanceWithMIL as FLOAT) + ELSE NULL + END as distanceWithMIL, + CASE + WHEN CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) != -255 THEN CAST(TripDataPoint.RelativeThrottlePosition as FLOAT) + ELSE NULL + END as relativeThrottlePos, + CASE + WHEN CAST(TripDataPoint.OutsideTemperature as FLOAT) != -255 THEN CAST(TripDataPoint.OutsideTemperature as FLOAT) + ELSE NULL + END as outsideTemperature, + CASE + WHEN CAST(TripDataPoint.EngineFuelRate as FLOAT) != -255 THEN CAST(TripDataPoint.EngineFuelRate as FLOAT) + ELSE NULL + END as engineFuelRate, + TripDataPoint.VIN as vin, TripDataPoint.RecordedTimeStamp as actualTS, DATEADD(millisecond,- DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp)) as ts, - DATEDIFF(millisecond, TripDataPoint.RecordedTimeStamp, DATEADD(millisecond,-DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp))) as tsDiff, - TripDataPoint.VIN as vin, - TripDataPoint.RelativeThrottlePosition as throttle + DATEDIFF(millisecond, TripDataPoint.RecordedTimeStamp, DATEADD(millisecond,-DATEPART(millisecond,TripDataPoint.RecordedTimeStamp),DATEADD(second, 5 - CAST(CEILING(DATEPART(second, TripDataPoint.RecordedTimeStamp)%5) as BIGINT),TripDataPoint.RecordedTimeStamp))) as tsDiff FROM CarDeviceData TIMESTAMP by TripDataPoint.RecordedTimeStamp WHERE