December 18, 2012 at 3:12 pm
I'm trying to get the count of only the Active Consumers for each ConsumerType, based on the ActivityDate.
Below are my sample queries
USE [Sample];
GO
--Create Table Consumer
CREATE TABLE [dbo].[Consumer](
[ConsumerID] [varchar](10) NOT NULL,
[ConsumerName] [varchar](100) NULL,
[ConsumerType] [varchar](20) NULL
) ON [PRIMARY]
GO
--Create Table ConsumerActivity
GO
CREATE TABLE [dbo].[ConsumerActivity](
[ConsumerID] [varchar](10) NOT NULL,
[ActivityDate] [datetime] NULL,
[Pts1] [numeric](9,0) NULL,
[Pts2] [numeric] (9,0) NULL,
[Status] [varchar] (10) NULL,
[Description] [varchar](100) NULL
) ON [PRIMARY]
GO
-- Insert some data into Consumer table
GO
INSERT INTO dbo.Consumer (ConsumerID, ConsumerName, ConsumerType)
VALUES ('1234', 'Jack Bennet','Elite')
GO
-- Insert some data into ConsumerActivity table
GO
INSERT INTO dbo.ConsumerActivity (ConsumerID, ActivityDate, Pts1, Pts2, Status, Description)
SELECT '1234','2012-06-04 00:00:00.000', 600,0, 'NEW','Pts earned on first time purchase'
UNION ALL
SELECT '1234','2012-08-20 00:00:00.000', 0,-200, NULL,'Points used for purchase'
UNION ALL
SELECT '1234','2012-10-20 00:00:00.000', 700,0, NULL,' Pts earned on New purchase'
UNION ALL
SELECT '1234','2012-10-25 00:00:00.000', 1200,-1200, 'DEACTIVATE','Account Deactivated and points adjusted'
GO
------------------------
SELECT Consumer.ConsumerType
,COUNT(DISTINCT ConsumerActivity.ConsumerID) as ConsumerCount
,SUM(ConsumerActivity.Pts1 + ConsumerActivity.Pts2) as PointsEarned
FROM dbo.Consumer
,dbo.ConsumerActivity
WHERE Consumer.ConsumerID = ConsumerActivity.ConsumerID
AND ConsumerActivity.ActivityDate < '2012-10-20 00:00:00.000'--This date should give us 1 count
GROUP BY Consumer.ConsumerType;
Now in the above query if I use the ActivityDate more than '10/25/2012' then this shouldn't count this particular Consumer as this Consumer has been deactivated.
When a Consumer is deactivated, their Status = "DEACTIVATE" is updated with a new ActivityDate in the table.
Thanks.
December 18, 2012 at 3:22 pm
Just a few clarifications, if I understand this right.
In the pts columns, for the final item, shouldn't pts1 be 0 and Pts2 be -1100 to zero the account off?
Can a customer be reactivated, or is DEACTIVATE always the last entry in the table for a particular ConsumerID? The reason for this is if you can get 'past' a deactivate you want only work from the most recent deactivation for totalling, which makes logging table detection a mite more complex.
Also, your script is a bit off, you #'d all the column names and left the main tables as regulars. I don't think that's what you meant to do... This works better:
IF OBJECT_ID('tempdb..#Consumer') IS NOT NULL
DROP TABLE #Consumer
IF OBJECT_ID('tempdb..#ConsumerActivity') IS NOT NULL
DROP TABLE #ConsumerActivity
--Create Table #Consumer
CREATE TABLE [dbo].[#Consumer](
[ConsumerID] [varchar](10) NOT NULL,
[ConsumerName] [varchar](100) NULL,
[ConsumerType] [varchar](20) NULL
) ON [PRIMARY]
GO
--Create Table #ConsumerActivity
GO
CREATE TABLE [dbo].[#ConsumerActivity](
[ConsumerID] [varchar](10) NOT NULL,
[ActivityDate] [datetime] NULL,
[Pts1] [numeric](9,0) NULL,
[Pts2] [numeric] (9,0) NULL,
[Status] [varchar] (10) NULL,
[Description] [varchar](100) NULL
) ON [PRIMARY]
GO
-- Insert some data into #Consumer table
GO
INSERT INTO dbo.#Consumer (ConsumerID, ConsumerName, ConsumerType)
VALUES ('1234', 'Jack Bennet','Elite')
GO
-- Insert some data into #ConsumerActivity table
GO
INSERT INTO dbo.#ConsumerActivity (ConsumerID, ActivityDate, Pts1, Pts2, Status, Description)
SELECT '1234','2012-06-04 00:00:00.000', 600,0, 'NEW','Pts earned on first time purchase'
UNION ALL
SELECT '1234','2012-08-20 00:00:00.000', 0,-200, NULL,'Points used for purchase'
UNION ALL
SELECT '1234','2012-10-20 00:00:00.000', 700,0, NULL,' Pts earned on New purchase'
UNION ALL
SELECT '1234','2012-10-25 00:00:00.000', 1200,-1200, 'DEACTIVATE','Account Deactivated and points adjusted'
GO
SELECT * FROM #Consumer
SELECT * FROM #ConsumerActivity
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 18, 2012 at 3:52 pm
Yes members can be reactivated. However, this reactivated members would be treated as a new members and we would only use the points they've earned after they've reactivated again. All of their previous points will be lost.
Regarding the points, whenever a member is deactivated, thier remaining points are adjusted and thats the reason you are seeing the same +ve and -ve numbers in two different columns. The key here is the ActivityDate and everytransaction is attached to it.
December 18, 2012 at 4:13 pm
sql1411 (12/18/2012)
Yes members can be reactivated. However, this reactivated members would be treated as a new members and we would only use the points they've earned after they've reactivated again. All of their previous points will be lost.
Would they use the same ConsumerID though?
Regarding the points, whenever a member is deactivated, thier remaining points are adjusted and thats the reason you are seeing the same +ve and -ve numbers in two different columns. The key here is the ActivityDate and everytransaction is attached to it.
Well, I'll assume it works for y'all. Seems a little odd from this side of the screen but isn't really associated with the direct concern you're having.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 19, 2012 at 3:45 pm
thats how the database has been set up and this is jsut one sample data for one member. Am I still confusing you on my question??
December 19, 2012 at 5:31 pm
Ignoring the valid questions posted by Evil, something like this might get you started:
--Create Table Consumer
CREATE TABLE #Consumer(
[ConsumerID] [varchar](10) NOT NULL,
[ConsumerName] [varchar](100) NULL,
[ConsumerType] [varchar](20) NULL
) ON [PRIMARY]
GO
--Create Table ConsumerActivity
GO
CREATE TABLE #ConsumerActivity(
[ConsumerID] [varchar](10) NOT NULL,
[ActivityDate] [datetime] NULL,
[Pts1] [numeric](9,0) NULL,
[Pts2] [numeric] (9,0) NULL,
[Status] [varchar] (10) NULL,
[Description] [varchar](100) NULL
) ON [PRIMARY]
GO
-- Insert some data into Consumer table
GO
INSERT INTO #Consumer (ConsumerID, ConsumerName, ConsumerType)
VALUES ('1234', 'Jack Bennet','Elite')
GO
-- Insert some data into ConsumerActivity table
GO
INSERT INTO #ConsumerActivity (ConsumerID, ActivityDate, Pts1, Pts2, Status, Description)
SELECT '1234','2012-06-04 00:00:00.000', 600,0, 'NEW','Pts earned on first time purchase'
UNION ALL
SELECT '1234','2012-08-20 00:00:00.000', 0,-200, NULL,'Points used for purchase'
UNION ALL
SELECT '1234','2012-10-20 00:00:00.000', 700,0, NULL,' Pts earned on New purchase'
UNION ALL
SELECT '1234','2012-10-25 00:00:00.000', 1200,-1200, 'DEACTIVATE','Account Deactivated and points adjusted'
DECLARE @AsOfDate DATETIME = '2012-10-25'
SELECT ConsumerType, ActiveOfType=COUNT(Status), Points=ISNULL(SUM(Points), 0)
FROM #Consumer a
LEFT OUTER JOIN (
SELECT ConsumerID, Status=MIN(Status), Points=SUM(Pts1 + Pts2)
FROM #ConsumerActivity
WHERE ActivityDate <= @AsOfDate
GROUP BY ConsumerID) b
ON a.ConsumerID = b.ConsumerID AND Status <> 'DEACTIVATE'
GROUP BY ConsumerType
DROP TABLE #Consumer
DROP TABLE #ConsumerActivity
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
December 20, 2012 at 1:46 pm
Seems like this is what I needed 🙂
Thanks guys.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply