I posted similar question
conditional count in a list of strings in SQL Oracle
this time the dataset is row wise but the logic remains the same. the items will be added to list1,2,3.. one by one. I used date when an item was added to the list.
here is the data
CREATE TABLE lists ( column1, column2 , column3) AS
SELECT 'list1', '01-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list1', '02-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list2', '01-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list2', '02-01-2020' , 'toy' FROM DUAL UNION ALL
SELECT 'list2', '03-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list3', '01-01-2020' , 'toy' FROM DUAL UNION ALL
SELECT 'list3', '02-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list3', '03-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list4', '01-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list4', '02-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list4', '03-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list5', '01-01-2020' , 'toy' FROM DUAL UNION ALL
SELECT 'list5', '02-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list5', '03-01-2020' , 'toy' FROM DUAL UNION ALL
SELECT 'list5', '04-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list6', '01-01-2020' , 'car' FROM DUAL UNION ALL
SELECT 'list6', '02-01-2020' , 'cards' FROM DUAL UNION ALL
SELECT 'list6', '03-01-2020' , 'toy' FROM DUAL UNION ALL
SELECT 'list6', '04-01-2020' , 'cards' FROM DUAL;
and the table looks like this
COLUMN1 COLUMN2 COLUMN3
list1 01-01-2020 car
list1 02-01-2020 car
list2 01-01-2020 car
list2 02-01-2020 toy
list2 03-01-2020 car
list3 01-01-2020 toy
list3 02-01-2020 cards
list3 03-01-2020 cards
list4 01-01-2020 car
list4 02-01-2020 cards
list4 03-01-2020 cards
list5 01-01-2020 toy
list5 02-01-2020 cards
list5 03-01-2020 toy
list5 04-01-2020 cards
list6 01-01-2020 car
list6 02-01-2020 cards
list6 03-01-2020 toy
list6 04-01-2020 cards
If there is just CAR in the list then you count number of cars. If there is non-car item then you count the first non-car item added to the list
e.g.
list1 car 2
list2 toy 1
list3 toy 1
list4 cards 2
list5 toy 2
list6 cards 2
You can use window functions to get the information about the lists which can then be used for filtering:
select l.column1, item_to_count,
count(*)
from (select l.*,
min(l.column2) keep (dense_rank first order by (case when l.column3 <> 'car' then 1 else 2 end), l.column2) over (partition by l.column1) as date_to_count,
min(l.column3) keep (dense_rank first order by (case when l.column3 <> 'car' then 1 else 2 end), l.column2) over (partition by l.column1) as item_to_count
from lists l
) l
where column3 = item_to_count and column2 >= date_to_count
group by l.column1, item_to_count
order by l.column1;
Here is a db<>fiddle.