A possible solution:

SELECT StoreFK;
        ,EmployeeFK;
        ,MIN(Sheetdate) AS WeekStart;
        ,MAX(RosterStart1) AS RosterStart1 ;
        ,MAX(RosterEnd1) AS RosterEnd1 ;
        ,MAX(WorkStart1) AS WorkStart1 ;
        ,MAX(WorkEnd1) AS WorkEnd1 ;
        ,MAX(RosterStart2) AS RosterStart2 ;
        ,MAX(RosterEnd2) AS RosterEnd2 ;
        ,MAX(WorkStart2) AS WorkStart2 ;
        ,MAX(WorkEnd2) AS WorkEnd2 ;
        ,MAX(RosterStart3) AS RosterStart3 ;
        ,MAX(RosterEnd3) AS RosterEnd3 ;
        ,MAX(WorkStart3) AS WorkStart3 ;
        ,MAX(WorkEnd3) AS WorkEnd3 ;
        ,MAX(RosterStart4) AS RosterStart4 ;
        ,MAX(RosterEnd4) AS RosterEnd4 ;
        ,MAX(WorkStart4) AS WorkStart4 ;
        ,MAX(WorkEnd4) AS WorkEnd4 ;
        ,MAX(RosterStart5) AS RosterStart5 ;
        ,MAX(RosterEnd5) AS RosterEnd5 ;
        ,MAX(WorkStart5) AS WorkStart5 ;
        ,MAX(WorkEnd5) AS WorkEnd5 ;
        ,MAX(RosterStart6) AS RosterStart6 ;
        ,MAX(RosterEnd6) AS RosterEnd6 ;
        ,MAX(WorkStart6) AS WorkStart6 ;
        ,MAX(WorkEnd6) AS WorkEnd6 ;
        ,MAX(RosterStart7) AS RosterStart7 ;
        ,MAX(RosterEnd7) AS RosterEnd7 ;
        ,MAX(WorkStart7) AS WorkStart7 ;
        ,MAX(WorkEnd7) AS WorkEnd7 ;
    FROM (;
SELECT A.StoreFK;
        ,A.EmployeeFK;
        ,A.SheetDate;
        ,IIF(DOW(A.SheetDate, 2) = 1, RosterStart, {::}) AS RosterStart1;
        ,IIF(DOW(A.SheetDate, 2) = 1, RosterEnd, {::}) AS RosterEnd1;
        ,IIF(DOW(A.SheetDate, 2) = 1, WorkStart, {::}) AS WorkStart1;
        ,IIF(DOW(A.SheetDate, 2) = 1, WorkEnd, {::}) AS WorkEnd1;
        ,IIF(DOW(A.SheetDate, 2) = 2, RosterStart, {::}) AS RosterStart2;
        ,IIF(DOW(A.SheetDate, 2) = 2, RosterEnd, {::}) AS RosterEnd2;
        ,IIF(DOW(A.SheetDate, 2) = 2, WorkStart, {::}) AS WorkStart2;
        ,IIF(DOW(A.SheetDate, 2) = 2, WorkEnd, {::}) AS WorkEnd2;
        ,IIF(DOW(A.SheetDate, 2) = 3, RosterStart, {::}) AS RosterStart3;
        ,IIF(DOW(A.SheetDate, 2) = 3, RosterEnd, {::}) AS RosterEnd3;
        ,IIF(DOW(A.SheetDate, 2) = 3, WorkStart, {::}) AS WorkStart3;
        ,IIF(DOW(A.SheetDate, 2) = 3, WorkEnd, {::}) AS WorkEnd3;
        ,IIF(DOW(A.SheetDate, 2) = 4, RosterStart, {::}) AS RosterStart4;
        ,IIF(DOW(A.SheetDate, 2) = 4, RosterEnd, {::}) AS RosterEnd4;
        ,IIF(DOW(A.SheetDate, 2) = 4, WorkStart, {::}) AS WorkStart4;
        ,IIF(DOW(A.SheetDate, 2) = 4, WorkEnd, {::}) AS WorkEnd4;
        ,IIF(DOW(A.SheetDate, 2) = 5, RosterStart, {::}) AS RosterStart5;
        ,IIF(DOW(A.SheetDate, 2) = 5, RosterEnd, {::}) AS RosterEnd5;
        ,IIF(DOW(A.SheetDate, 2) = 5, WorkStart, {::}) AS WorkStart5;
        ,IIF(DOW(A.SheetDate, 2) = 5, WorkEnd, {::}) AS WorkEnd5;
        ,IIF(DOW(A.SheetDate, 2) = 6, RosterStart, {::}) AS RosterStart6;
        ,IIF(DOW(A.SheetDate, 2) = 6, RosterEnd, {::}) AS RosterEnd6;
        ,IIF(DOW(A.SheetDate, 2) = 6, WorkStart, {::}) AS WorkStart6;
        ,IIF(DOW(A.SheetDate, 2) = 6, WorkEnd, {::}) AS WorkEnd6;
        ,IIF(DOW(A.SheetDate, 2) = 7, RosterStart, {::}) AS RosterStart7;
        ,IIF(DOW(A.SheetDate, 2) = 7, RosterEnd, {::}) AS RosterEnd7;
        ,IIF(DOW(A.SheetDate, 2) = 7, WorkStart, {::}) AS WorkStart7;
        ,IIF(DOW(A.SheetDate, 2) = 7, WorkEnd, {::}) AS WorkEnd7;
    FROM (;
    SELECT TD.EmployeeFK;
            ,T.SheetDate;
            ,T.StoreFK;
            ,TD.StartTime as WorkStart;
            ,TD.EndTime as WorkEnd;
        from TimeSheetDetails TD ;
            INNER JOIN TimeSheets T ON TD.TimeSheetFK = T.TimeSheetPK ;
            WHERE NOT T.isRoster) A;
        INNER JOIN (;
        SELECT RD.EmployeeFK;
            ,R.SheetDate;
            ,R.StoreFK;
            ,RD.StartTime as RosterStart;
            ,RD.EndTime as RosterEnd;
        from TimeSheetDetails RD ;
            INNER JOIN TimeSheets R ON RD.TimeSheetFK = R.TimeSheetPK ;
            WHERE R.isRoster;
            ) B ON A.EmployeeFK = B.EmployeeFK AND A.SheetDate = B.SheetDate AND A.StoreFK = B.StoreFK;
        ) S ;
    GROUP BY StoreFK, EmployeeFK;
    INTO CURSOR c_TimeWorkedSummary

Frank.

Frank Cazabon

On 22/07/2021 9:11 am, Frank Cazabon wrote:
Hi,

I haven't done a lot of VFP recently so I've forgotten some basics. I need to manipulate some data for reporting purposes. Here's some sample code:CREATE CURSOR TimeSheets ;
(TimeSheetPK i,;
StoreFK i,;
Sheetdate d,;
isRoster l)

CREATE CURSOR TimeSheetDetails ;
(TimeSheetDetailsPK i,;
TimeSheetFK i,;
EmployeeFK i,;
StartTime T,;
EndTime T)

* roster time scheduled to work
INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (1, 1, DATE(2021, 7, 12), .T.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (2, 1, DATE(2021, 7, 13), .T.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (3, 1, DATE(2021, 7, 14), .T.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (4, 1, DATE(2021, 7, 15), .T.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (5, 1, DATE(2021, 7, 16), .T.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (6, 1, DATE(2021, 7, 17), .T.)

* Employee 1
INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (1, 1, 1, DATETIME(2021, 7, 12, 8, 0), DATETIME(2021, 7, 12, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (2, 3, 1, DATETIME(2021, 7, 14, 8, 0), DATETIME(2021, 7, 14, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (3, 4, 1, DATETIME(2021, 7, 15, 8, 0), DATETIME(2021, 7, 15, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (4, 6, 1, DATETIME(2021, 7, 17, 8, 0), DATETIME(2021, 7, 17, 16, 0))

* Employee 2
INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (5, 1, 2, DATETIME(2021, 7, 12, 8, 0), DATETIME(2021, 7, 12, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (6, 2, 2, DATETIME(2021, 7, 13, 8, 0), DATETIME(2021, 7, 13, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (7, 3, 2, DATETIME(2021, 7, 14, 8, 0), DATETIME(2021, 7, 14, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (8, 4, 2, DATETIME(2021, 7, 15, 8, 0), DATETIME(2021, 7, 15, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (9, 6, 2, DATETIME(2021, 7, 17, 8, 0), DATETIME(2021, 7, 17, 16, 0))

* record actual time worked
INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (7, 1, DATE(2021, 7, 12), .F.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (8, 1, DATE(2021, 7, 13), .F.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (9, 1, DATE(2021, 7, 14), .F.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (10, 1, DATE(2021, 7, 15), .F.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (11, 1, DATE(2021, 7, 16), .F.) INSERT INTO TimeSheets (TimeSheetPK, StoreFK, SheetDate, isRoster) VALUES (12, 1, DATE(2021, 7, 17), .F.)

* Employee 1
INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (10, 7, 1, DATETIME(2021, 7, 12, 8, 30), DATETIME(2021, 7, 12, 16, 30)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (11, 9, 1, DATETIME(2021, 7, 14, 8, 10), DATETIME(2021, 7, 14, 16, 10)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (12, 10, 1, DATETIME(2021, 7, 15, 8, 20), DATETIME(2021, 7, 15, 16, 20)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (13, 12, 1, DATETIME(2021, 7, 17, 8, 40), DATETIME(2021, 7, 17, 16, 40))

* Employee 2
INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (14, 7, 2, DATETIME(2021, 7, 12, 7, 0), DATETIME(2021, 7, 12, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (15, 8, 2, DATETIME(2021, 7, 13, 7, 45), DATETIME(2021, 7, 13, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (16, 9, 2, DATETIME(2021, 7, 14, 8, 5), DATETIME(2021, 7, 14, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (17, 10, 2, DATETIME(2021, 7, 15, 8, 15), DATETIME(2021, 7, 15, 16, 0)) INSERT INTO TimeSheetDetails (TimeSheetDetailsPK, TimeSheetFK, EmployeeFK, StartTime, EndTime) VALUES (18, 12, 2, DATETIME(2021, 7, 17, 8, 25), DATETIME(2021, 7, 17, 16, 0))

* I need to build the data above into a cursor like this preferably using SQL.
* The data is currently VFP but will shortly be moving to SQL Server
* so you can use fastxtab if necessary as I should be able to change that to pivot table:

CREATE CURSOR TimeRosteredAndWorked;
(StoreFK i,;
WeekStart D,;
EmployeeFK i,;
RosterStart1 T NULL,;
RosterEnd1 T NULL,;
WorkedStart1 T NULL,;
WorkedEnd1 T NULL,;
RosterStart2 T NULL,;
RosterEnd2 T NULL,;
WorkedStart2 T NULL,;
WorkedEnd2 T NULL,;
RosterStart3 T NULL,;
RosterEnd3 T NULL,;
WorkedStart3 T NULL,;
WorkedEnd3 T NULL,;
RosterStart4 T NULL,;
RosterEnd4 T NULL,;
WorkedStart4 T NULL,;
WorkedEnd4 T NULL,;
RosterStart5 T NULL,;
RosterEnd5 T NULL,;
WorkedStart5 T NULL,;
WorkedEnd5 T NULL,;
RosterStart6 T NULL,;
RosterEnd6 T NULL,;
WorkedStart6 T NULL,;
WorkedEnd6 T NULL,;
RosterStart7 T NULL,;
RosterEnd7 T NULL,;
WorkedStart7 T NULL,;
WorkedEnd7 T NULL)

* Employee 1
INSERT INTO TimeRosteredAndWorked ;
    (StoreFK,;
    WeekStart,;
    EmployeeFK,;
    RosterStart1,;
    RosterEnd1,;
    WorkedStart1,;
    WorkedEnd1,;
    RosterStart2,;
    RosterEnd2,;
    WorkedStart2,;
    WorkedEnd2,;
    RosterStart3,;
    RosterEnd3,;
    WorkedStart3,;
    WorkedEnd3,;
    RosterStart4,;
    RosterEnd4,;
    WorkedStart4,;
    WorkedEnd4,;
    RosterStart5,;
    RosterEnd5,;
    WorkedStart5,;
    WorkedEnd5,;
    RosterStart6,;
    RosterEnd6,;
    WorkedStart6,;
    WorkedEnd6,;
    RosterStart7,;
    RosterEnd7,;
    WorkedStart7 ,;
    WorkedEnd7);
VALUES ;
    (1,;
    DATE(2021, 7, 12),;
    1,;
    DATETIME(2021, 7, 12, 8, 0),;
    DATETIME(2021, 7, 12, 16, 0),;
    DATETIME(2021, 7, 12, 8, 30),;
    DATETIME(2021, 7, 12, 16, 30),;
    NULL,;
    NULL,;
    NULL,;
    NULL,;
    DATETIME(2021, 7, 14, 8, 0),;
    DATETIME(2021, 7, 14, 16, 0),;
    DATETIME(2021, 7, 14, 8, 10),;
    DATETIME(2021, 7, 14, 16, 10),;
    DATETIME(2021, 7, 15, 8, 0),;
    DATETIME(2021, 7, 15, 16, 0),;
    DATETIME(2021, 7, 15, 8, 20),;
    DATETIME(2021, 7, 15, 16, 20),;
    NULL,;
    NULL,;
    NULL,;
    NULL,;
    DATETIME(2021, 7, 17, 8, 0),;
    DATETIME(2021, 7, 17, 16, 0),;
    DATETIME(2021, 7, 17, 8, 40),;
    DATETIME(2021, 7, 17, 16, 40),;
    NULL,;
    NULL,;
    NULL,;
    NULL)

* Employee 2
INSERT INTO TimeRosteredAndWorked ;
    (StoreFK,;
    WeekStart,;
    EmployeeFK,;
    RosterStart1,;
    RosterEnd1,;
    WorkedStart1,;
    WorkedEnd1,;
    RosterStart2,;
    RosterEnd2,;
    WorkedStart2,;
    WorkedEnd2,;
    RosterStart3,;
    RosterEnd3,;
    WorkedStart3,;
    WorkedEnd3,;
    RosterStart4,;
    RosterEnd4,;
    WorkedStart4,;
    WorkedEnd4,;
    RosterStart5,;
    RosterEnd5,;
    WorkedStart5,;
    WorkedEnd5,;
    RosterStart6,;
    RosterEnd6,;
    WorkedStart6,;
    WorkedEnd6,;
    RosterStart7,;
    RosterEnd7,;
    WorkedStart7 ,;
    WorkedEnd7);
VALUES ;
    (1,;
    DATE(2021, 7, 12),;
    2,;
    DATETIME(2021, 7, 12, 8, 0),;
    DATETIME(2021, 7, 12, 16, 0),;
    DATETIME(2021, 7, 12, 7, 0),;
    DATETIME(2021, 7, 12, 16, 0),;
    DATETIME(2021, 7, 13, 8, 0),;
    DATETIME(2021, 7, 13, 16, 0),;
    DATETIME(2021, 7, 13, 7, 45),;
    DATETIME(2021, 7, 13, 16, 0),;
    DATETIME(2021, 7, 14, 8, 0),;
    DATETIME(2021, 7, 14, 16, 0),;
    DATETIME(2021, 7, 14, 8, 5),;
    DATETIME(2021, 7, 14, 16, 0),;
    DATETIME(2021, 7, 15, 8, 0),;
    DATETIME(2021, 7, 15, 16, 0),;
    DATETIME(2021, 7, 15, 8, 15),;
    DATETIME(2021, 7, 15, 16, 0),;
    NULL,;
    NULL,;
    NULL,;
    NULL,;
    DATETIME(2021, 7, 17, 8, 0),;
    DATETIME(2021, 7, 17, 16, 0),;
    DATETIME(2021, 7, 17, 8, 25),;
    DATETIME(2021, 7, 17, 16, 0),;
    NULL,;
    NULL,;
    NULL,;
    NULL)

I have used fastxtab which gets me close but the column names are based on the dates whereas I want to have fixed names for reference in the report, it also results in a separate row for each date for each employee whereas I want 1 row for each employee.

Any suggestions as to the best way to approach this?


_______________________________________________
Post Messages to: ProFox@leafe.com
Subscription Maintenance: https://mail.leafe.com/mailman/listinfo/profox
OT-free version of this list: https://mail.leafe.com/mailman/listinfo/profoxtech
Searchable Archive: https://leafe.com/archives
This message: 
https://leafe.com/archives/byMID/da3986f5-5605-cc2f-35cb-f209a2c25...@gmail.com
** All postings, unless explicitly stated otherwise, are the opinions of the 
author, and do not constitute legal or medical advice. This statement is added 
to the messages for those lawyers who are too stupid to see the obvious.

Reply via email to