This commit is contained in:
Nick Salch 2023-03-21 13:36:17 -07:00
Родитель 2d0eda4204
Коммит d79ed8172f
3 изменённых файлов: 207 добавлений и 4 удалений

Просмотреть файл

@ -459,7 +459,7 @@ WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY total_tempdb.total_tempdb_gb
/*
--Tempdb usage per query
SELECT
'TempDB per query' AS 'TempDB per query'
@ -475,6 +475,18 @@ WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY req.request_id
ORDER BY bytes_written desc
*/
/***************************************************************************
Procedure name: sp_tempdb_node
Description: lists various information about tempdb usage
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_tempdb_node')
EXEC ('CREATE PROC dbo.sp_tempdb_node AS SELECT ''TEMPORARY''')
GO
ALTER PROC sp_tempdb_node AS
--Tempdb usage per node
SELECT
@ -585,6 +597,7 @@ WITH step_data AS
--, type
FROM sys.dm_pdw_dms_workers
WHERE status != 'StepComplete'
AND type != 'Writer' --including writers gives you double counts on operations
Group by
request_id
, step_index
@ -598,7 +611,7 @@ SELECT
, rs.operation_type
, (step_data.Step_elapsed_time/1000/60) AS 'step_elapsed_time_(m)'
, step_data.Step_rows_processed
, step_data.step_bytes_processed
--, step_data.step_bytes_processed
, (step_data.Step_Bytes_Processed/1024/1024/1024) AS Step_GB_Processed
, step_data.step_index
--, step_data.type

Просмотреть файл

@ -181,6 +181,7 @@ SELECT
,dist.end_time
,dist.spid
,rs.command
,dist.source_info AS 'distribution_source_command'
,dist.error_id
FROM
(--dms
@ -201,6 +202,7 @@ SELECT
,bytes_processed
,rows_processed AS row_count
,command AS dist_text
,source_info
FROM sys.dm_pdw_dms_workers
WHERE request_id = @request_id
@ -217,7 +219,8 @@ SELECT
,start_time
,end_time
,total_elapsed_time
,command
,command
,-1 AS 'distribution_source_command'
,error_id
,spid
,-1 AS bytes_per_sec
@ -582,6 +585,7 @@ WITH step_data AS
--, type
FROM sys.dm_pdw_dms_workers
WHERE status != 'StepComplete'
AND type != 'Writer' --including writers gives you double counts on operations
Group by
request_id
, step_index
@ -595,7 +599,7 @@ SELECT
, rs.operation_type
, (step_data.Step_elapsed_time/1000/60) AS 'step_elapsed_time_(m)'
, step_data.Step_rows_processed
, step_data.step_bytes_processed
--, step_data.step_bytes_processed
, (step_data.Step_Bytes_Processed/1024/1024/1024) AS Step_GB_Processed
, step_data.step_index
--, step_data.type

Просмотреть файл

@ -0,0 +1,186 @@
SET
NOCOUNT ON
DROP TABLE dbo.Employee;
GO
CREATE TABLE dbo.Employee (
EmployeeId BIGINT NOT NULL,
EmployeeName VARCHAR(255) NOT NULL,
ParentId BIGINT NOT NULL
) WITH (
DISTRIBUTION = HASH (EmployeeId),
HEAP
);
GO
insert into
Employee
values
(10, 'Ken Sánchez', 1);
insert into
Employee
values
(11, 'Brian Welker', 10);
insert into
Employee
values
(12, 'Stephen Jiang', 11);
insert into
Employee
values
(13, 'Michael Blythe', 2);
insert into
Employee
values
(14, 'Linda Mitchell', 13);
insert into
Employee
values
(15, 'Syed Abbas', 3);
insert into
Employee
values
(16, 'Lynn Tsoflias', 15);
insert into
Employee
values
(17, 'David Bradley', 16);
insert into
Employee
values
(18, 'Hanan Almira', 17);
insert into
Employee
values
(19, 'Yunia Damayanti', 18);
insert into
Employee
values
(20, 'Mike Decker', 19);
insert into
Employee
values
(21, 'Lovely Sugiyanti', 12);
GO
SELECT
*
FROM
dbo.Employee f
-- Insert first record where no parent exists
IF OBJECT_ID('tempdb..#employee') IS NOT NULL DROP TABLE #employee;
CREATE TABLE #employee
WITH (
DISTRIBUTION = HASH (EmployeeId)
) AS
WITH cte AS (
SELECT
1 AS xlevel,
p.EmployeeId,
p.ParentId,
p.EmployeeName,
CAST(p.ParentId AS VARCHAR(255)) AS PathString,
0 AS PathLength,
1 as IsRoot,
Case when exists (Select 1 from dbo.employee pcheck where pcheck.ParentId = p.EmployeeID) then 0 else 1 end as IsLeaf
FROM
dbo.Employee p
WHERE
NOT EXISTS (
SELECT
*
FROM
dbo.Employee c
WHERE
p.ParentId = c.EmployeeId
)
)
SELECT
*
FROM
cte
SELECT
'before' s,
*
FROM
#employee
ORDER BY EmployeeId;
-- Loop thru Features
DECLARE @counter int = 1;
--Begin Loop
WHILE EXISTS (
SELECT
*
FROM
#employee p
INNER JOIN dbo.employee c ON p.EmployeeId = c.ParentId
WHERE
p.xlevel = @counter
)
BEGIN -- Insert next level
INSERT INTO
#employee ( xlevel, EmployeeId, ParentId, EmployeeName, PathString, PathLength, IsRoot, IsLeaf )
SELECT
@counter + 1 AS xlevel,
c.EmployeeId,
c.ParentId,
c.EmployeeName,
p.PathString + '*' + CAST(c.ParentId AS VARCHAR(255)) AS PathString,
@counter AS PathLength,
0 as IsRoot,
Case when exists (Select 1 from dbo.employee pcheck where pcheck.ParentId = C.EmployeeID) then 0 else 1 end as IsLeaf
FROM
#employee p
INNER JOIN dbo.employee c ON p.EmployeeId = c.ParentId
WHERE
p.xlevel = @counter;
SET @counter = @counter + 1;
-- Loop safety
IF @counter > 99
BEGIN
RAISERROR('Too many loops!', 16, 1)
BREAK
END
END
SELECT
*
FROM
dbo.Employee f
SELECT
'after' s,
*
FROM
#employee ORDER BY EmployeeId;
--Get Leaf Rows
SELECT
'after' s,
*
FROM
#employee e
Where not exists (select parentid from #Employee p where e.employeeid = p.parentid)