I am beginner of SQL. How do I save the query result of Part A (already have multiple subqueries using WITH clause) as a new temp table, so that I can use it for the query in Part B (because the aggregation in Part B is based on Part A)? In the end, I would like to have results of Part A and Part B separately. I've tried to solution from other posts, but it doesn't seem to work for my problem as I have multiple subqueries using the WITH clause). Thank you in advance for your help!
/****** Part A ******/
WITH DL_source AS
(SELECT
LogID
,HashID
,DeviceDateTime
,LAG(DeviceDateTime, 1) OVER (PARTITION BY HashID ORDER BY HashID, DeviceDateTime, LogID) AS Last_DeviceDateTime
,TotalSecondsSpent
,PageViews
,Pages
,PrevPage
,IEM
,CommCode
,ContentTag
,SearchKeyword
,TaggedMember
,TargetMember
FROM (SELECT
ROW_NUMBER() OVER(ORDER BY HashID, DeviceDate, HourOfDay, MinOfHour, SecOfMin) AS LogID
,HashID
,CAST(DeviceDate AS DATETIME)
+ CAST(TIMEFROMPARTS(HourOfDay, MinOfHour, SecOfMin,0 ,0) AS DATETIME) AS DeviceDateTime
,TotalSecondsSpent
,PageViews
,Pages
,PrevPage
,IEM
,CommCode
,ContentTag
,SearchKeyword
,TaggedMember
,TargetMember
FROM [DM_RAW].[dbo].[WebAnalyticsVisit]
WHERE DeviceDate IS NOT NULL
AND DeviceDate <> '1900-01-01'
AND HashID IS NOT NULL
AND HashID <> '') AS DL_DateTime),
DL_Session_Source AS (
SELECT
LogID
,HashID
,DeviceDateTime
,Last_DeviceDateTime
,DATEDIFF(MINUTE, DeviceDateTime, LEAD(DeviceDateTime, 1) OVER(PARTITION BY HashID ORDER BY DeviceDateTime ASC)) AS Min_btw_Page
,CASE WHEN DATEDIFF(minute, Last_DeviceDateTime, DeviceDateTime) <30 THEN 0 ELSE 1 END AS New_Session_flag
,TotalSecondsSpent
,PageViews
,Pages
,PrevPage
,IEM
,CommCode
,ContentTag
,SearchKeyword
,TaggedMember
,TargetMember
FROM DL_source)
SELECT
LogID
,HashID
,DeviceDateTime
,Last_DeviceDateTime
,Min_btw_Page
,New_Session_flag
,SUM(New_Session_flag) OVER (ORDER BY HashID, DeviceDateTime, LogID) AS Session_Num
,TotalSecondsSpent
,PageViews
,Pages
,PrevPage
,IEM
,CommCode
,ContentTag
,SearchKeyword
,TaggedMember
,TargetMember
FROM DL_Session_Source
/****** Part B ******/
SELECT *,
Session_Num
,HashID
,COUNT(*) AS Num_Page
,MIN(DeviceDateTime) AS First_Page
,MAX(DeviceDateTime) AS Last_Page
FROM #cte_Visit_Record_cheunghm4532
GROUP BY Session_Num, HashID
Quick'n'easy option: When you get to the SELECT part at the bottom of Part A, put an INTO expression in.
Note for these statements, I have reduced the number of fields etc and replaced with ...
for brevity/clarity.
WITH DL_source AS
(SELECT
... ),
DL_Session_Source AS (
SELECT ...
FROM DL_source)
SELECT
LogID
,HashID
...
,TargetMember
INTO #cte_Visit_Record_cheunghm4532 -- Added this row
FROM DL_Session_Source;
Note that the above creates a new table - it will not insert into an existing table.
A more thorough/flexible version is to first create the temporary table, then instead of the SELECT above, make it an INSERT e.g.,
CREATE TABLE #cte_Visit_Record_cheunghm4532 (LogID int, HashID varchar(32), ...);
WITH DL_source AS
(SELECT
... ),
DL_Session_Source AS (
SELECT ...
FROM DL_source)
INSERT INTO #cte_Visit_Record_cheunghm4532 (LogID, HashID, ...)
SELECT LogID
,HashID
...
FROM DL_Session_Source;