Click here to Skip to main content
15,891,136 members
Please Sign up or sign in to vote.
0.00/5 (No votes)
See more:
Hello, Please, I need to separete the quantity of clients we had sell them products by sellers in a period of a month.
The query I have is this but it doesn`t work:
SQL
select * 
from (select SELLER, DATE, CLIENT
      from proddta.SALE where SELLER in ('JHON', 'MATH', 'PETER'))
PIVOT (
       count(DISTINCT(CLIENT)) as QUANTITY_CLIENT FOR DATE in  
          (case when DATE between 01/05/14 and 13/05/14 as 01 end), 
          (case when DATE between 14/05/14 and 22/05/14 as 02 end),
          (case when DATE between 23/05/14 and 30/05/14 as 03 end)
          );

My doubt is after the "IN" but perhaps I am writng it wrong from the beggining.


The output would be the following

-------NumberOfclientsPeriod_01|NumberOfClientsPeriod02|NumberofclientsPeriod03
JHON------------23 --------------------------24----------------------20
MATH------------20 --------------------------22----------------------21
PETER------------24--------------------------21----------------------22
Posted
Updated 21-Jul-14 10:08am
v7
Comments
Andrius Leonavicius 21-Jul-14 15:46pm    
Hi,

It would be easier to help you if you could post input and output samples...
Member 10960881 21-Jul-14 16:09pm    
Hi Andrius, the output would be the following:

-------NumberOfclientsPeriod_01|NumberOfClientsPeriod02|NumberofclientsPeriod03
JHON------------23 --------------------------24----------------------20
MATH------------20 --------------------------22----------------------21
PETER------------24--------------------------21----------------------22
Member 10960881 21-Jul-14 16:12pm    
It works well for single days like:
select *
from (select SELLER, DATE, CLIENT
from proddta.SALE where SELLER in ('JHON', 'MATH', 'PETER'))
PIVOT (
count(DISTINCT(CLIENT)) as QUANTITY_CLIENT FOR DATE in (01/05/14, 02/05/14, 03/05/14)

But i am needing to range the date

1 solution

It would be something like this:
SQL
DECLARE @SALE TABLE (SELLER VARCHAR(30), [DATE] DATETIME, CLIENT VARCHAR(30))

INSERT INTO @SALE (SELLER, [DATE], CLIENT )
VALUES('JHON','2014-05-01','A'), ('JHON','2014-05-07','B'), ('JHON','2014-05-09','C'), ('JHON','2014-05-14','E'), ('JHON','2014-05-15','A'), ('JHON','2014-05-18','D'),
('MATH','2014-05-20','A'), ('MATH','2014-05-21','B'), ('MATH','2014-05-22','C'), ('MATH','2014-05-25','D'), ('MATH','2014-05-28','C'), ('MATH','2014-05-28','C'), 
('PETER','2014-05-29','A'), ('PETER','2014-05-29','B'), ('PETER','2014-05-30','D'), ('PETER','2014-05-30','D'), ('PETER','2014-05-30','E'), ('PETER','2014-05-30','A') 


SELECT *
FROM @SALE 

SELECT SELLER, [01], [02], [03]
FROM (
		SELECT SELLER, Period, COUNT(DISTINCT CLIENT) AS NOFClients
		FROM (
			SELECT SELLER, [Period] = CASE WHEN [DATE] BETWEEN '2014-05-01' AND '2014-05-13' THEN '01'
                                      WHEN [DATE] BETWEEN '2014-05-14' AND '2014-05-22' THEN '02'
                                      WHEN [DATE] BETWEEN '2014-05-23' AND '2014-05-30' THEN '03'
                      END, CLIENT
			FROM @SALE
			) AS T
      WHERE SELLER IN ('JHON', 'MATH', 'PETER')
      GROUP BY SELLER, [Period]
     ) AS DT
PIVOT(SUM(NOFClients) FOR [Period] IN ([01], [02], [03])) AS PT


Results:
JHON    2014-05-01 00:00:00.000 A
JHON    2014-05-07 00:00:00.000 B
JHON    2014-05-09 00:00:00.000 C
JHON    2014-05-14 00:00:00.000 E
JHON    2014-05-15 00:00:00.000 A
JHON    2014-05-18 00:00:00.000 D
MATH    2014-05-20 00:00:00.000 A
MATH    2014-05-21 00:00:00.000 B
MATH    2014-05-22 00:00:00.000 C
MATH    2014-05-25 00:00:00.000 D
MATH    2014-05-28 00:00:00.000 C
MATH    2014-05-28 00:00:00.000 C
PETER   2014-05-29 00:00:00.000 A
PETER   2014-05-29 00:00:00.000 B
PETER   2014-05-30 00:00:00.000 D
PETER   2014-05-30 00:00:00.000 D
PETER   2014-05-30 00:00:00.000 E
PETER   2014-05-30 00:00:00.000 A


e=text
JHON    3       3   NULL
MATH    NULL    3   2
PETER   NULL    NULL    4


For further information, please see:
CASE[^]
PIVOT and UNPIVOT[^]
Aggregate Functions (Transact-SQL)[^]
 
Share this answer
 
v4
Comments
Member 10960881 21-Jul-14 17:56pm    
It says there is a "missing expression". It has logically and I understand it very well the difference with mine now. Does we are missing something to solve this error?
Maciej Los 21-Jul-14 18:09pm    
Please, see my answer after update.
Member 10960881 22-Jul-14 7:59am    
Hi Maciej, Thanks for your interest! I run the SQL but it says "missing expression". Please, could you revise if there is something that we are missing? I am still comparing with others in the web but it seams to be OK..
Maciej Los 22-Jul-14 8:23am    
See updated answer ;)
Member 10960881 22-Jul-14 8:45am    
GENIOUS! Thanks for your answer, it works fine at this time!!!

This content, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)



CodeProject, 20 Bay Street, 11th Floor Toronto, Ontario, Canada M5J 2N8 +1 (416) 849-8900