-- ============================================================ -- ChnPrmShip 캐시 검증 진단 쿼리 -- 대상: t_std_snp_data.ais_target (일별 파티션) -- 목적: 최근 2일 내 대상 MMSI별 최종위치 캐싱 검증 -- ============================================================ -- ============================================================ -- 0. 대상 MMSI 임시 테이블 생성 -- ============================================================ CREATE TEMP TABLE tmp_chn_mmsi (mmsi BIGINT PRIMARY KEY); -- psql에서 실행: -- \copy tmp_chn_mmsi(mmsi) FROM 'chnprmship-mmsi.txt' -- ============================================================ -- 1. 기본 현황: 대상 MMSI 중 최근 2일 내 데이터 존재 여부 -- ============================================================ SELECT (SELECT COUNT(*) FROM tmp_chn_mmsi) AS total_target_mmsi, COUNT(DISTINCT a.mmsi) AS mmsi_with_data_2d, (SELECT COUNT(*) FROM tmp_chn_mmsi) - COUNT(DISTINCT a.mmsi) AS mmsi_without_data_2d, ROUND(COUNT(DISTINCT a.mmsi) * 100.0 / NULLIF((SELECT COUNT(*) FROM tmp_chn_mmsi), 0), 1) AS hit_rate_pct FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '2 days'; -- ============================================================ -- 2. 워밍업 시뮬레이션: 최근 2일 내 MMSI별 최종위치 -- (수정 후 findLatestByMmsiIn 쿼리와 동일하게 동작) -- ============================================================ SELECT COUNT(*) AS cached_count, MIN(message_timestamp) AS oldest_cached, MAX(message_timestamp) AS newest_cached, NOW() - MAX(message_timestamp) AS newest_age FROM ( SELECT DISTINCT ON (a.mmsi) a.mmsi, a.message_timestamp FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '2 days' ORDER BY a.mmsi, a.message_timestamp DESC ) latest; -- ============================================================ -- 3. MMSI별 최종위치 상세 (최근 2일 내, 최신순 상위 30건) -- ============================================================ SELECT DISTINCT ON (a.mmsi) a.mmsi, a.message_timestamp, a.name, a.vessel_type, a.lat, a.lon, a.sog, a.cog, a.heading, NOW() - a.message_timestamp AS data_age FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '2 days' ORDER BY a.mmsi, a.message_timestamp DESC LIMIT 30; -- ============================================================ -- 4. 데이터 없는 대상 MMSI (최근 2일 내 DB에 없는 선박) -- ============================================================ SELECT t.mmsi AS missing_mmsi FROM tmp_chn_mmsi t LEFT JOIN ( SELECT DISTINCT mmsi FROM t_std_snp_data.ais_target WHERE mmsi IN (SELECT mmsi FROM tmp_chn_mmsi) AND message_timestamp >= NOW() - INTERVAL '2 days' ) a ON t.mmsi = a.mmsi WHERE a.mmsi IS NULL ORDER BY t.mmsi; -- ============================================================ -- 5. 시간대별 분포 (2일 기준 세부 확인) -- ============================================================ SELECT '6시간 이내' AS time_range, COUNT(DISTINCT mmsi) AS distinct_mmsi FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '6 hours' UNION ALL SELECT '12시간 이내', COUNT(DISTINCT mmsi) FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '12 hours' UNION ALL SELECT '1일 이내', COUNT(DISTINCT mmsi) FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '1 day' UNION ALL SELECT '2일 이내', COUNT(DISTINCT mmsi) FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi WHERE a.message_timestamp >= NOW() - INTERVAL '2 days' UNION ALL SELECT '전체(무제한)', COUNT(DISTINCT mmsi) FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi; -- ============================================================ -- 6. 파티션별 대상 데이터 분포 -- ============================================================ SELECT tableoid::regclass AS partition_name, COUNT(*) AS row_count, COUNT(DISTINCT mmsi) AS distinct_mmsi, MIN(message_timestamp) AS min_ts, MAX(message_timestamp) AS max_ts FROM t_std_snp_data.ais_target a JOIN tmp_chn_mmsi t ON a.mmsi = t.mmsi GROUP BY tableoid::regclass ORDER BY max_ts DESC; -- ============================================================ -- 7. 전체 ais_target 파티션 현황 -- ============================================================ SELECT c.relname AS partition_name, pg_size_pretty(pg_relation_size(c.oid)) AS table_size, s.n_live_tup AS estimated_rows FROM pg_inherits i JOIN pg_class c ON c.oid = i.inhrelid JOIN pg_stat_user_tables s ON s.relid = c.oid WHERE i.inhparent = 't_std_snp_data.ais_target'::regclass ORDER BY c.relname DESC; -- ============================================================ -- 정리 -- ============================================================ DROP TABLE IF EXISTS tmp_chn_mmsi;