RESET IN VERTICA
Hello All,
I have in TeraData
Select PER_ID, CONTACT_ID, START_DT, PREV_CONTACT_ID,
ROW_NUMBER() Over (Partition By PER_ID Order By START_DT RESET WHEN PREV_CONTACT_ID Is Null) As CONTACT_SERIES
Explanation: if in partition a column PREV_CONTACT_ID has a value NULL, in this case the ROW_NUMBER must restarts from 1.
But in Vertica does not exists: 'OVER (.... RESET WHEN condition)'. How can I write similar condition in Vertica?
Tried conditional true event and change event but it does not work that way.
0
Answers
Blast from the past!
See:
http://www.vertica-forums.com/viewtopic.php?t=2095
Same answer today?
Nice Jim!
@hdk0310,
It would be very helpful, if you could provide a small executable sample with create table and data. Based on your query I am making assumptions about your data. For example, I thought per_id is the primary key. Can start_dt be null or repeat?
More verbose alternative below:
Hi ,
@Jim and Sudhakar
Thanks for your response. I tried both the solutions but somehow it is not helping me achieve the objective as my data set is different.
Data set:
PER_ID,Global_PER_ID,START_DT (timestamp field),PREV_CONTACT = (possible values = 'A','B',NULL)
Teradata logic: (working in Teradata)
,sum(case when PREV_CONTACT is not null then 1 else 0 end) OVER (PARTITION BY PER_ID, Global_PER_ID ORDER BY PER_ID, Global_PER_ID, START_DT RESET WHEN PREV_CONTACT is null ROWS UNBOUNDED PRECEDING ) as ConsecutiveIntervals
Vertica: (Tried Vertica Alternative)
,CONDITIONAL_TRUE_EVENT(PREV_CONTACT is not null ) over (PARTITION by PER_ID, Global_PER_ID ORDER BY PER_ID, Global_PER_ID,START_DT) AS ConsecutiveIntervals
To Achieve ConsecutiveIntervals:
Current_SysTime Per_ID Global_Per_ID STart_DT Prev_Contact ConsecutiveIntervals
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 9:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 9:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 9:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 8:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:20 A 3
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:10 A 2
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 7:00 A 1
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 6:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 5:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 4:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 3:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:20 A 1
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 2:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:40 A 1
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 1:00 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:50 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:40 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:30 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:20 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:10 NULL 0
2019-08-30 09:23:21+00:00 50000 1500 30/08/19 0:00 NULL 0
Thanks
How about this?
Example:
Thanks @Jim_Knicely . It worked as expected.
Cool!