January 31, 2023 at 3:00 pm
Hi guys,
I want some help with a code to count the number of unique months that appears in list (use created code below).
For example: ZipCode 14171 got 5 hits, but the unique months are 3 and that's the expected output.
Could someone please help with that?
Thanks! 🙂
CREATE TABLE #mytable
(
[UCLogTimeStamp] DATE,
[ZipCode] INT,
)
;
SET DATEFORMAT DMY
;
INSERT INTO #mytable
([UCLogTimeStamp], [ZipCode])
VALUES
('2018-12-13',14171)
,('2018-11-13',14171)
,('2018-11-13',14171)
,('2018-10-13',14171)
,('2018-10-13',14171)
,('2018-12-13',45634)
,('2018-11-13',45634)
,('2018-11-13',45634)
,('2018-10-13',45634)
,('2018-09-13',45634)
SELECT [UCLogTimeStamp]
, [ZipCode] FROM #mytable
January 31, 2023 at 3:41 pm
SELECT ZipCode, COUNT(DISTINCT DATEADD(MONTH, DATEDIFF(MONTH, 0, UCLogTimeStamp), 0)) AS 'No. months'
FROM #mytable
GROUP BY ZipCode
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
January 31, 2023 at 3:58 pm
Works perfect, thanks Scott!!
January 31, 2023 at 4:30 pm
As alternatives to the DATEADD DATEDIFF formula, you can also use the new DATETRUNC function
COUNT(DISTINCT DATETRUNC(Month, UCLogTimeStamp))
or the old conversion to a fixed-lenght char type (ISO style yyyy-mm)
COUNT(DISTINCT CAST(UCLogTimeStamp AS CHAR(7)))
January 31, 2023 at 4:42 pm
BTW, there isn't really a need for the outer DATEADD in Scott's query, since you only need to count the distinct number of months since 1900-01-01, which is what the DATEDIFF function returns (please correct me if I'm wrong).
SELECT ZipCode, COUNT(DISTINCT DATEDIFF(MONTH, 0, UCLogTimeStamp)) AS 'No. months'
FROM #mytable
GROUP BY ZipCode
February 1, 2023 at 8:38 am
This was removed by the editor as SPAM
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply