February 21, 2013 at 8:43 am
I feel like I've been staring at this statement for hours and just keep mangling it more. Any help would be appreciated.
I want to select all records from tipTransactionPivot and salesExport. If there are the same values for rvcID, employeeID, and businessDate, then I want to join them. Otherwise, I'd like to return them with null values for the other table.
I also want to get certain values from the employee table joined on either the microsEmployeeNumber (in the case of salesExport) or employeeID (in the case of tipTransactionPivot).
Like I said, I probably have this pretty mangled at this point, so I'm sure there is a better way to do it.
P.S. I know it would be better to do some of this in an application rather than in SQL, but it isn't really an option, so I need to return SQL results from a single query if at all possible.
SELECT dbo.salesExport.businessDate, dbo.salesExport.rvcID, dbo.employee.employeeID, dbo.employee.employeeFName, dbo.employee.employeeLName,
dbo.salesExport.chargedReceipts, dbo.salesExport.grossReceipts - dbo.salesExport.chargedReceipts AS otherReceipts,
dbo.salesExport.grossReceipts, dbo.salesExport.discountTotal, dbo.salesExport.bqtSvc19, dbo.salesExport.bqtSvc20, CONVERT(numeric(18, 2),
dbo.salesExport.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS bqt20Sales,
CONVERT(numeric(18, 2), ((dbo.salesExport.grossReceipts + dbo.salesExport.discountTotal) + dbo.salesExport.bqtSvc19 / 0.19 * - 1)
+ dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS netSales, dbo.salesExport.chargedTips, dbo.employee.microsEmployeeNumber,
ISNULL(dbo.tipTransactionPivot.cashTips, 0) AS cashTips, ISNULL(dbo.tipTransactionPivot.cashTipsOut, 0) AS cashTipsOut,
ISNULL(dbo.tipTransactionPivot.cashTipsIn, 0) AS cashTipsIn, ISNULL(dbo.tipTransactionPivot.chargeTipsOut, 0) AS chargeTipsOut,
ISNULL(dbo.tipTransactionPivot.chargeTipsIn, 0) AS chargeTipsIn
FROM dbo.employee AS employee_1 INNER JOIN
dbo.tipTransactionPivot ON employee_1.employeeID = dbo.tipTransactionPivot.employeeID FULL OUTER JOIN
dbo.employee RIGHT OUTER JOIN
dbo.salesExport ON dbo.employee.microsEmployeeNumber = dbo.salesExport.microsEmployeeNumber ON
employee_1.microsEmployeeNumber = dbo.salesExport.microsEmployeeNumber AND
dbo.tipTransactionPivot.businessDate = dbo.salesExport.businessDate AND dbo.tipTransactionPivot.rvcID = dbo.salesExport.rvcID
February 21, 2013 at 9:02 am
Hello,
Please try below query...may be you have to tweak it to suit your requirement....hope this helps
SELECTdbo.salesExport.businessDate, dbo.salesExport.rvcID
, dbo.employee.employeeID, dbo.employee.employeeFName, dbo.employee.employeeLName
, dbo.salesExport.chargedReceipts, dbo.salesExport.grossReceipts - dbo.salesExport.chargedReceipts AS otherReceipts
, dbo.salesExport.grossReceipts, dbo.salesExport.discountTotal, dbo.salesExport.bqtSvc19, dbo.salesExport.bqtSvc20, CONVERT(numeric(18, 2),
dbo.salesExport.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS bqt20Sales,
CONVERT(numeric(18, 2), ((dbo.salesExport.grossReceipts + dbo.salesExport.discountTotal) + dbo.salesExport.bqtSvc19 / 0.19 * - 1)
+ dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS netSales, dbo.salesExport.chargedTips, dbo.employee.microsEmployeeNumber,
ISNULL(dbo.tipTransactionPivot.cashTips, 0) AS cashTips, ISNULL(dbo.tipTransactionPivot.cashTipsOut, 0) AS cashTipsOut,
ISNULL(dbo.tipTransactionPivot.cashTipsIn, 0) AS cashTipsIn, ISNULL(dbo.tipTransactionPivot.chargeTipsOut, 0) AS chargeTipsOut,
ISNULL(dbo.tipTransactionPivot.chargeTipsIn, 0) AS chargeTipsIn
FROM dbo.tipTransactionPivot
FULL OUTER JOIN dbo.salesExport
ON dbo.tipTransactionPivot.employeeID = dbo.salesExport.microsEmployeeNumber
AND dbo.tipTransactionPivot.businessDate = dbo.salesExport.businessDate
AND dbo.tipTransactionPivot.rvcID = dbo.salesExport.rvcID
LEFT JOIN dbo.employee
ON dbo.employee.microsEmployeeNumber = dbo.tipTransactionPivot.employeeID
February 21, 2013 at 9:03 am
You appear to have 2 'ON' clauses in the RIGHT OUTER JOIN.
You could use aliases to simplify the code & make it more readable...
Like this:
SELECT SAL.businessDate, SAL.rvcID, EMP2.employeeID, EMP2.employeeFName, EMP2.employeeLName,
SAL.chargedReceipts, SAL.grossReceipts - SAL.chargedReceipts AS otherReceipts,
SAL.grossReceipts, SAL.discountTotal, SAL.bqtSvc19, SAL.bqtSvc20, CONVERT(numeric(18, 2),
SAL.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), SAL.bqtSvc20 / 0.20 * - 1) AS bqt20Sales,
CONVERT(numeric(18, 2), ((SAL.grossReceipts + SAL.discountTotal) + SAL.bqtSvc19 / 0.19 * - 1)
+ SAL.bqtSvc20 / 0.20 * - 1) AS netSales, SAL.chargedTips, EMP1.microsEmployeeNumber,
ISNULL(PIV.cashTips, 0) AS cashTips, ISNULL(PIV.cashTipsOut, 0) AS cashTipsOut,
ISNULL(PIV.cashTipsIn, 0) AS cashTipsIn, ISNULL(PIV.chargeTipsOut, 0) AS chargeTipsOut,
ISNULL(PIV.chargeTipsIn, 0) AS chargeTipsIn
FROM dbo.tipTransactionPivot PIV FULL OUTER JOIN
dbo.salesExport SAL ON SAL.rvcID = PIV.rvcID and SAL.employeeID = PIV.employeeID and SAL.businessDate = PIV.businessDate LEFT OUTER JOIN
dbo.employee EMP1 ON EMP1.employeeID = PIV.employeeID LEFT OUTER JOIN
dbo.employee EMP2 ON EMP2.employeeID = SAL.microsEmployeeNumber
Note that EMP1.microsEmployeeNumber should be SAL.microsEmployeeNumber I think...
February 21, 2013 at 9:43 am
I tried this, but I'm having the same problem I seem to have had with the other approaches I've taken. In this case, I'm getting a number of NULL values for the information that is coming from the employee table (I believe for everything that doesn't have a matching entry in the tipTransactionPivot table).
asiaindian (2/21/2013)
Hello,Please try below query...may be you have to tweak it to suit your requirement....hope this helps
SELECTdbo.salesExport.businessDate, dbo.salesExport.rvcID
, dbo.employee.employeeID, dbo.employee.employeeFName, dbo.employee.employeeLName
, dbo.salesExport.chargedReceipts, dbo.salesExport.grossReceipts - dbo.salesExport.chargedReceipts AS otherReceipts
, dbo.salesExport.grossReceipts, dbo.salesExport.discountTotal, dbo.salesExport.bqtSvc19, dbo.salesExport.bqtSvc20, CONVERT(numeric(18, 2),
dbo.salesExport.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS bqt20Sales,
CONVERT(numeric(18, 2), ((dbo.salesExport.grossReceipts + dbo.salesExport.discountTotal) + dbo.salesExport.bqtSvc19 / 0.19 * - 1)
+ dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS netSales, dbo.salesExport.chargedTips, dbo.employee.microsEmployeeNumber,
ISNULL(dbo.tipTransactionPivot.cashTips, 0) AS cashTips, ISNULL(dbo.tipTransactionPivot.cashTipsOut, 0) AS cashTipsOut,
ISNULL(dbo.tipTransactionPivot.cashTipsIn, 0) AS cashTipsIn, ISNULL(dbo.tipTransactionPivot.chargeTipsOut, 0) AS chargeTipsOut,
ISNULL(dbo.tipTransactionPivot.chargeTipsIn, 0) AS chargeTipsIn
FROM dbo.tipTransactionPivot
FULL OUTER JOIN dbo.salesExport
ON dbo.tipTransactionPivot.employeeID = dbo.salesExport.microsEmployeeNumber
AND dbo.tipTransactionPivot.businessDate = dbo.salesExport.businessDate
AND dbo.tipTransactionPivot.rvcID = dbo.salesExport.rvcID
LEFT JOIN dbo.employee
ON dbo.employee.microsEmployeeNumber = dbo.tipTransactionPivot.employeeID
February 21, 2013 at 10:09 am
Is this code generated by a tool?
For better assistance in answering your questions, please read this[/url].
Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]
February 21, 2013 at 10:11 am
ChrisM@home (2/21/2013)
Is this code generated by a tool?
SQL Query Designer - since I can't seem to get there manually, either.
February 21, 2013 at 10:28 am
mkswanson (2/21/2013)
I tried this, but I'm having the same problem I seem to have had with the other approaches I've taken. In this case, I'm getting a number of NULL values for the information that is coming from the employee table (I believe for everything that doesn't have a matching entry in the tipTransactionPivot table).asiaindian (2/21/2013)
Hello,Please try below query...may be you have to tweak it to suit your requirement....hope this helps
SELECTdbo.salesExport.businessDate, dbo.salesExport.rvcID
, dbo.employee.employeeID, dbo.employee.employeeFName, dbo.employee.employeeLName
, dbo.salesExport.chargedReceipts, dbo.salesExport.grossReceipts - dbo.salesExport.chargedReceipts AS otherReceipts
, dbo.salesExport.grossReceipts, dbo.salesExport.discountTotal, dbo.salesExport.bqtSvc19, dbo.salesExport.bqtSvc20, CONVERT(numeric(18, 2),
dbo.salesExport.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS bqt20Sales,
CONVERT(numeric(18, 2), ((dbo.salesExport.grossReceipts + dbo.salesExport.discountTotal) + dbo.salesExport.bqtSvc19 / 0.19 * - 1)
+ dbo.salesExport.bqtSvc20 / 0.20 * - 1) AS netSales, dbo.salesExport.chargedTips, dbo.employee.microsEmployeeNumber,
ISNULL(dbo.tipTransactionPivot.cashTips, 0) AS cashTips, ISNULL(dbo.tipTransactionPivot.cashTipsOut, 0) AS cashTipsOut,
ISNULL(dbo.tipTransactionPivot.cashTipsIn, 0) AS cashTipsIn, ISNULL(dbo.tipTransactionPivot.chargeTipsOut, 0) AS chargeTipsOut,
ISNULL(dbo.tipTransactionPivot.chargeTipsIn, 0) AS chargeTipsIn
FROM dbo.tipTransactionPivot
FULL OUTER JOIN dbo.salesExport
ON dbo.tipTransactionPivot.employeeID = dbo.salesExport.microsEmployeeNumber
AND dbo.tipTransactionPivot.businessDate = dbo.salesExport.businessDate
AND dbo.tipTransactionPivot.rvcID = dbo.salesExport.rvcID
LEFT JOIN dbo.employee
ON dbo.employee.microsEmployeeNumber = dbo.tipTransactionPivot.employeeID
You need to join to Employee twice - once for each main tablein the query. Since either table may have null values in the row, you must 'LEFT OUTER JOIN' to Employee. this will result in null values in Employee - so you must make sure you refer to the values of the correct instance of Employee.
For instance, if dbo.salesExport is non-null & it is joined to EMP1 - EMP1 values will be non-null. If in the same row, dbo.tipTransactionPivot has null values (ie no matching records), then EMP2 will have null values.
February 21, 2013 at 11:22 am
Success! Thanks for everyone's help!
SELECT SAL.businessDate, SAL.rvcID, EMP1.employeeID, EMP1.employeeFName, EMP1.employeeLName, SAL.chargedReceipts, SAL.grossReceipts - SAL.chargedReceipts AS otherReceipts,
SAL.grossReceipts, SAL.discountTotal, SAL.bqtSvc19, SAL.bqtSvc20, CONVERT(numeric(18, 2), SAL.bqtSvc19 / 0.19 * - 1) AS bqt19Sales, CONVERT(numeric(18, 2), SAL.bqtSvc20 / 0.20 * - 1)
AS bqt20Sales, CONVERT(numeric(18, 2), ((SAL.grossReceipts + SAL.discountTotal) + SAL.bqtSvc19 / 0.19 * - 1) + SAL.bqtSvc20 / 0.20 * - 1) AS netSales, SAL.chargedTips, ISNULL(PIV.cashTips, 0)
AS cashTips, ISNULL(PIV.cashTipsOut, 0) AS cashTipsOut, ISNULL(PIV.cashTipsIn, 0) AS cashTipsIn, ISNULL(PIV.chargeTipsOut, 0) AS chargeTipsOut, ISNULL(PIV.chargeTipsIn, 0) AS chargeTipsIn
FROM employee AS EMP1 RIGHT OUTER JOIN
salesExport AS SAL ON EMP1.microsEmployeeNumber = SAL.microsEmployeeNumber LEFT OUTER JOIN
tipTransactionPivot AS PIV ON SAL.rvcID = PIV.rvcID AND SAL.microsEmployeeNumber = PIV.microsEmployeeNumber AND SAL.businessDate = PIV.businessDate
WHERE (EMP1.employeeID IS NOT NULL)
UNION ALL
SELECT PIV.businessDate, PIV.rvcID, EMP2.employeeID, EMP2.employeeFName, EMP2.employeeLName, CONVERT(numeric(18, 2), '0') AS Expr1, CONVERT(numeric(18, 2), '0') AS Expr2,
CONVERT(numeric(18, 2), '0') AS Expr3, CONVERT(numeric(18, 2), '0') AS Expr4, CONVERT(numeric(18, 2), '0') AS Expr5, CONVERT(numeric(18, 2), '0') AS Expr6, CONVERT(numeric(18, 2), '0')
AS Expr7, CONVERT(numeric(18, 2), '0') AS Expr8, CONVERT(numeric(18, 2), '0') AS Expr9, CONVERT(numeric(18, 2), '0') AS Expr10, ISNULL(PIV.cashTips, 0) AS Expr11, ISNULL(PIV.cashTipsOut, 0)
AS cashTipsOut, ISNULL(PIV.cashTipsIn, 0) AS cashTipsIn, ISNULL(PIV.chargeTipsOut, 0) AS chargeTipsOut, ISNULL(PIV.chargeTipsIn, 0) AS chargeTipsIn
FROM tipTransactionPivot AS PIV LEFT OUTER JOIN
employee AS EMP2 ON PIV.microsEmployeeNumber = EMP2.microsEmployeeNumber FULL OUTER JOIN
salesExport AS SAL ON PIV.rvcID = SAL.rvcID AND PIV.microsEmployeeNumber = SAL.microsEmployeeNumber AND PIV.businessDate = SAL.businessDate
WHERE (SAL.businessDate IS NULL)
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply