238 lines
11 KiB
SQL
238 lines
11 KiB
SQL
-- 获取最新的数据
|
||
select to_timestamp(max(timestamp))
|
||
from activities;
|
||
|
||
-- 获取最旧的数据
|
||
select to_timestamp(min(timestamp))
|
||
from activities;
|
||
|
||
-- 数据总量
|
||
select max(activity_id) - min(activity_id) + 1 from activities;
|
||
|
||
-- 1天内的数据,按action分组排序
|
||
select b.action_id, b.action, count(b.action_id)
|
||
from activities as a
|
||
left join actions as b on a.action_id = b.action_id
|
||
where timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by b.action_id, b.action
|
||
order by count(b.action_id) desc;
|
||
|
||
-- 1天内的block-place行为按玩家分组
|
||
select cause_player_id, players.player, count(*)
|
||
from activities
|
||
left join players on activities.cause_player_id = players.player_id
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by cause_player_id, player
|
||
order by count(cause_player_id) desc;
|
||
|
||
-- 1天内,非明确实体触发的block-place行为
|
||
select *
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and cause_id is not null
|
||
limit 500;
|
||
|
||
-- 1天内,非玩家触发的block-place行为,按entity_type
|
||
select cause_entity_type_id, entity_type, count(*)
|
||
from activities
|
||
left join entity_types on activities.cause_entity_type_id = entity_types.entity_type_id
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and cause_player_id is null
|
||
group by cause_entity_type_id, entity_type
|
||
order by count(cause_entity_type_id) desc;
|
||
|
||
-- 1天内,非明确实体触发的block-place行为,按cause_id分组
|
||
select activities.cause_id, causes.cause, count(*)
|
||
from activities
|
||
left join causes on activities.cause_id = causes.cause_id
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and activities.cause_id is not null
|
||
group by activities.cause_id, causes.cause
|
||
order by count(activities.cause_id) desc;
|
||
|
||
-- 1天内,nature引发的block-place事件,按坐标分组并排序
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and cause_id = (select cause_id from causes where cause = 'nature')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,unknown 引发的 block-place 事件,按坐标分组并排序
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-place')
|
||
and cause_id = (select cause_id from causes where cause = 'unknown')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内的 block-break 行为按玩家分组
|
||
select cause_player_id, players.player, count(*)
|
||
from activities
|
||
left join players on activities.cause_player_id = players.player_id
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by cause_player_id, player
|
||
order by count(cause_player_id) desc;
|
||
|
||
-- 1天内,非玩家触发的 block-break 行为,按 cause_id 分组
|
||
select activities.cause_id, causes.cause, count(*)
|
||
from activities
|
||
left join causes on activities.cause_id = causes.cause_id
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and activities.cause_player_id is null
|
||
group by activities.cause_id, causes.cause
|
||
order by count(activities.cause_id) desc;
|
||
|
||
-- 1天内,非玩家触发的 block-break 行为,按 type_id 分组
|
||
select activities.cause_entity_type_id, entity_types.entity_type, count(*)
|
||
from activities
|
||
left join entity_types on activities.cause_entity_type_id = entity_types.entity_type_id
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and activities.cause_player_id is null
|
||
group by activities.cause_entity_type_id, entity_types.entity_type
|
||
order by count(activities.cause_id) desc;
|
||
|
||
-- 1天内,活塞破换方块,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id = (select causes.cause_id from causes where cause = 'piston')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,活塞破换方块,按方块类型分组
|
||
select blocks.name, count((affected_block_id, blocks.name))
|
||
from activities
|
||
left join blocks on activities.affected_block_id = blocks.block_id
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id = (select causes.cause_id from causes where cause = 'piston')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by affected_block_id, blocks.name
|
||
order by count((affected_block_id, blocks.name)) desc;
|
||
|
||
-- 1天内,爆炸破换方块,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id = (select causes.cause_id from causes where cause = 'explosion')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,爆炸破换方块,按方块类型分组
|
||
select blocks.name, count((affected_block_id, blocks.name))
|
||
from activities
|
||
left join blocks on activities.affected_block_id = blocks.block_id
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id = (select causes.cause_id from causes where cause = 'explosion')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by affected_block_id, blocks.name
|
||
order by count((affected_block_id, blocks.name)) desc;
|
||
|
||
-- 1天内,decay 破换方块,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id = (select causes.cause_id from causes where cause = 'decay')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,非明确实体触发的block-break行为,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_id is not null
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,风弹实体触发的 block-break 行为,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
and cause_entity_type_id = (select entity_type_id from entity_types where entity_type = 'breeze_wind_charge')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 查看最近风弹破换方块的数据
|
||
select *
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-break')
|
||
-- and cause_entity_type_id = (select entity_type_id from entity_types where entity_type = 'breeze_wind_charge')
|
||
and cause_entity_type_id is null
|
||
and cause_player_id is null
|
||
and cause_id is null
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
limit 100;
|
||
|
||
-- 1天内,item-dispense行为,按发射的物品分组统计
|
||
select descriptor, count(*)
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'item-dispense')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by descriptor
|
||
order by count(descriptor) desc;
|
||
|
||
-- 1天内,item-dispense行为,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'item-dispense')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内,item-dispense行为,按坐标与物品分组
|
||
select world_id, x, y, z, descriptor, count((world_id, x, y, z, descriptor))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'item-dispense')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z, descriptor
|
||
order by count((world_id, x, y, z, descriptor)) desc;
|
||
|
||
-- 1天内,发射的矿车,按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'item-dispense')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
and descriptor = 'Minecart'
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|
||
|
||
-- 1天内的 entity-death 行为按玩家分组
|
||
select cause_player_id, players.player, count(*)
|
||
from activities
|
||
left join players on activities.cause_player_id = players.player_id
|
||
where action_id = (select action_id from actions where action = 'entity-death')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by cause_player_id, player
|
||
order by count(cause_player_id) desc;
|
||
|
||
-- 1天内的 entity-death 按实体分组
|
||
select affected_entity_type_id, entity_types.entity_type, count(*)
|
||
from activities
|
||
left join entity_types on activities.affected_entity_type_id = entity_types.entity_type_id
|
||
where action_id = (select action_id from actions where action = 'entity-death')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by affected_entity_type_id, entity_types.entity_type
|
||
order by count(*) desc;
|
||
|
||
-- 1天内的 block-form 行为按坐标分组
|
||
select world_id, x, y, z, count((world_id, x, y, z))
|
||
from activities
|
||
where action_id = (select action_id from actions where action = 'block-form')
|
||
and timestamp > EXTRACT(EPOCH FROM current_timestamp(0))::bigint - 86400 * 1
|
||
group by world_id, x, y, z
|
||
order by count((world_id, x, y, z)) desc;
|