1 | | == Напреден апликативен развој == |
| 1 | = Напреден апликативен развој — Anomalyzer = |
| 2 | |
| 3 | |
| 4 | |
| 5 | Имплементирани се: |
| 6 | * **Изведени колони** (year, month_year, fraction_date) преку BEFORE тригер |
| 7 | * **Автоматска дневна агрегaција** во табела `events_daily_agg` по INSERT/UPDATE/DELETE |
| 8 | * **Бизнис правила** со CHECK и тригер (граници на tone; non-root настаните мора да имаат mentions) |
| 9 | * **Оптимизација на перформанси** со индекси за чести join/filter полиња |
| 10 | |
| 11 | == Тригери == |
| 12 | |
| 13 | === BEFORE INSERT/UPDATE на events === |
| 14 | |
| 15 | Нормализација на кодови, проверка на валидност и автоматско пополнување на деривирани полиња (`year`, `month_year`, `fraction_date`). |
| 16 | |
| 17 | {{{ |
| 18 | CREATE OR REPLACE FUNCTION trg_events_before_ins_upd() |
| 19 | RETURNS trigger |
| 20 | LANGUAGE plpgsql |
| 21 | AS $$ |
| 22 | BEGIN |
| 23 | IF NEW.event_code IS NOT NULL THEN |
| 24 | NEW.event_code := upper(NEW.event_code); |
| 25 | END IF; |
| 26 | |
| 27 | IF NEW.avg_tone IS NOT NULL AND (NEW.avg_tone < -10 OR NEW.avg_tone > 10) THEN |
| 28 | RAISE EXCEPTION 'avg_tone out of range [-10,10]: %', NEW.avg_tone; |
| 29 | END IF; |
| 30 | |
| 31 | IF NEW.sql_date IS NOT NULL THEN |
| 32 | NEW.year := EXTRACT(YEAR FROM NEW.sql_date)::int; |
| 33 | NEW.month_year := to_char(NEW.sql_date, 'MMYYYY'); |
| 34 | NEW.fraction_date := EXTRACT(DOY FROM NEW.sql_date) / 365.0; |
| 35 | END IF; |
| 36 | |
| 37 | IF NEW.is_root_event IS FALSE AND COALESCE(NEW.num_mentions, 0) <= 0 THEN |
| 38 | RAISE EXCEPTION 'non-root events must have num_mentions > 0'; |
| 39 | END IF; |
| 40 | |
| 41 | RETURN NEW; |
| 42 | END; |
| 43 | $$; |
| 44 | |
| 45 | CREATE TRIGGER events_before_ins_upd |
| 46 | BEFORE INSERT OR UPDATE ON events |
| 47 | FOR EACH ROW |
| 48 | EXECUTE FUNCTION trg_events_before_ins_upd(); |
| 49 | }}} |
| 50 | |
| 51 | === AFTER INSERT/UPDATE/DELETE на events === |
| 52 | |
| 53 | Автоматско пресметување на дневна агрегaција и чување во табелата `events_daily_agg`. |
| 54 | |
| 55 | {{{ |
| 56 | CREATE TABLE IF NOT EXISTS events_daily_agg ( |
| 57 | sql_date DATE PRIMARY KEY, |
| 58 | events_count INTEGER NOT NULL, |
| 59 | avg_tone NUMERIC(6,4) |
| 60 | ); |
| 61 | |
| 62 | CREATE OR REPLACE FUNCTION trg_events_after_ins_upd_del() |
| 63 | RETURNS trigger |
| 64 | LANGUAGE plpgsql |
| 65 | AS $$ |
| 66 | BEGIN |
| 67 | WITH s AS ( |
| 68 | SELECT d AS sql_date, COUNT(*) AS events_count, AVG(avg_tone) AS avg_tone |
| 69 | FROM (SELECT COALESCE(NEW.sql_date, OLD.sql_date) AS d) q |
| 70 | JOIN events e ON e.sql_date = q.d |
| 71 | GROUP BY d |
| 72 | ) |
| 73 | INSERT INTO events_daily_agg(sql_date, events_count, avg_tone) |
| 74 | SELECT sql_date, events_count, avg_tone FROM s |
| 75 | ON CONFLICT (sql_date) DO UPDATE |
| 76 | SET events_count = EXCLUDED.events_count, |
| 77 | avg_tone = EXCLUDED.avg_tone; |
| 78 | |
| 79 | IF NOT EXISTS ( |
| 80 | SELECT 1 FROM events WHERE sql_date = COALESCE(NEW.sql_date, OLD.sql_date) |
| 81 | ) THEN |
| 82 | DELETE FROM events_daily_agg WHERE sql_date = COALESCE(NEW.sql_date, OLD.sql_date); |
| 83 | END IF; |
| 84 | |
| 85 | RETURN NULL; |
| 86 | END; |
| 87 | $$; |
| 88 | |
| 89 | CREATE TRIGGER events_after_ins |
| 90 | AFTER INSERT ON events |
| 91 | FOR EACH ROW |
| 92 | EXECUTE FUNCTION trg_events_after_ins_upd_del(); |
| 93 | |
| 94 | CREATE TRIGGER events_after_upd |
| 95 | AFTER UPDATE ON events |
| 96 | FOR EACH ROW |
| 97 | EXECUTE FUNCTION trg_events_after_ins_upd_del(); |
| 98 | |
| 99 | CREATE TRIGGER events_after_del |
| 100 | AFTER DELETE ON events |
| 101 | FOR EACH ROW |
| 102 | EXECUTE FUNCTION trg_events_after_ins_upd_del(); |
| 103 | }}} |
| 104 | |
| 105 | == Трансакции == |
| 106 | |
| 107 | CRUD операциите врз `events` се извршуваат во рамки на трансакициски блокови. |
| 108 | Во Django, ова се постигнува со `@transaction.atomic`, што овозможува автоматски ROLLBACK при грешка (нпр. кога тригер ќе подигне исклучок). |
| 109 | |
| 110 | Пример: |
| 111 | |
| 112 | {{{ |
| 113 | # src/api/views/events.py |
| 114 | from django.db import transaction |
| 115 | from rest_framework.response import Response |
| 116 | from rest_framework.views import APIView |
| 117 | from .services.events import event_create |
| 118 | |
| 119 | class EventListCreate(APIView): |
| 120 | @transaction.atomic |
| 121 | def post(self, request): |
| 122 | payload = request.data |
| 123 | out = event_create(payload) # повик на p_event_create |
| 124 | return Response(out, status=201) |
| 125 | }}} |
| 126 | |
| 127 | == Индекси == |
| 128 | |
| 129 | За перформанси при пребарување и join операции, креирани се индекси: |
| 130 | |
| 131 | {{{ |
| 132 | CREATE INDEX ix_event_details_event ON event_details (global_event_id); |
| 133 | CREATE INDEX ix_event_details_actor ON event_details (actor_id); |
| 134 | CREATE INDEX ix_event_details_loc ON event_details (location_id); |
| 135 | |
| 136 | CREATE INDEX ix_notifications_user ON notifications (user_id, notification_date); |
| 137 | CREATE INDEX ix_notifications_event ON notifications (event_id); |
| 138 | |
| 139 | CREATE INDEX ix_predictions_event ON predictions (event_id); |
| 140 | CREATE INDEX ix_predictions_actor ON predictions (actor_id); |
| 141 | |
| 142 | CREATE INDEX ix_analytics_event_actor ON event_analytics (event_id, actor_id, date); |
| 143 | CREATE INDEX ix_conflict_pair_date ON conflict_risk (actor1_id, actor2_id, predicted_date); |
| 144 | }}} |
| 145 | |
| 146 | == Складирани процедури == |
| 147 | |
| 148 | Имплементирани се CRUD процедури за `events`, со JSON резултат погоден за директен REST одговор. |
| 149 | |
| 150 | === p_event_create === |
| 151 | {{{ |
| 152 | CREATE OR REPLACE PROCEDURE p_event_create( |
| 153 | IN p_sql_date date, |
| 154 | IN p_is_root_event boolean, |
| 155 | IN p_event_code varchar(10), |
| 156 | IN p_goldstein_scale numeric(5,2) DEFAULT NULL, |
| 157 | IN p_num_mentions int DEFAULT NULL, |
| 158 | IN p_num_sources int DEFAULT NULL, |
| 159 | IN p_num_articles int DEFAULT NULL, |
| 160 | IN p_avg_tone numeric(5,2) DEFAULT NULL, |
| 161 | INOUT p_result refcursor DEFAULT NULL |
| 162 | ) |
| 163 | LANGUAGE plpgsql |
| 164 | AS $$ |
| 165 | DECLARE v_id int; |
| 166 | BEGIN |
| 167 | INSERT INTO events ( |
| 168 | sql_date, month_year, year, fraction_date, is_root_event, event_code, |
| 169 | goldstein_scale, num_mentions, num_sources, num_articles, avg_tone |
| 170 | ) |
| 171 | VALUES ( |
| 172 | p_sql_date, TO_CHAR(p_sql_date,'MMYYYY'), |
| 173 | EXTRACT(YEAR FROM p_sql_date)::int, |
| 174 | (EXTRACT(DOY FROM p_sql_date)::numeric / 365), |
| 175 | COALESCE(p_is_root_event, TRUE), p_event_code, |
| 176 | p_goldstein_scale, p_num_mentions, p_num_sources, p_num_articles, p_avg_tone |
| 177 | ) |
| 178 | RETURNING global_event_id INTO v_id; |
| 179 | |
| 180 | IF p_result IS NULL THEN p_result := 'cur_event_create'; END IF; |
| 181 | OPEN p_result FOR SELECT to_jsonb(e) AS j FROM events e WHERE e.global_event_id = v_id; |
| 182 | END; |
| 183 | $$; |
| 184 | }}} |
| 185 | |
| 186 | === p_event_get === |
| 187 | {{{ |
| 188 | CREATE OR REPLACE PROCEDURE p_event_get( |
| 189 | IN p_event_id int, |
| 190 | INOUT p_result refcursor DEFAULT NULL |
| 191 | ) |
| 192 | LANGUAGE plpgsql |
| 193 | AS $$ |
| 194 | BEGIN |
| 195 | IF p_result IS NULL THEN p_result := 'cur_event_get'; END IF; |
| 196 | OPEN p_result FOR |
| 197 | SELECT COALESCE( |
| 198 | (SELECT to_jsonb(e) FROM events e WHERE e.global_event_id = p_event_id), |
| 199 | jsonb_build_object('ok', false, 'error', 'not_found', 'id', p_event_id) |
| 200 | ) AS j; |
| 201 | END; |
| 202 | $$; |
| 203 | }}} |
| 204 | |
| 205 | === p_event_list === |
| 206 | {{{ |
| 207 | CREATE OR REPLACE PROCEDURE p_event_list( |
| 208 | IN p_limit int DEFAULT 50, |
| 209 | IN p_offset int DEFAULT 0, |
| 210 | INOUT p_result refcursor DEFAULT NULL |
| 211 | ) |
| 212 | LANGUAGE plpgsql |
| 213 | AS $$ |
| 214 | BEGIN |
| 215 | IF p_result IS NULL THEN p_result := 'cur_event_list'; END IF; |
| 216 | OPEN p_result FOR |
| 217 | WITH rows AS ( |
| 218 | SELECT to_jsonb(e) AS j |
| 219 | FROM events e |
| 220 | ORDER BY e.global_event_id DESC |
| 221 | LIMIT GREATEST(p_limit,0) OFFSET GREATEST(p_offset,0) |
| 222 | ) |
| 223 | SELECT jsonb_build_object( |
| 224 | 'ok', true, |
| 225 | 'limit', p_limit, |
| 226 | 'offset', p_offset, |
| 227 | 'results', COALESCE(jsonb_agg(j), '[]'::jsonb) |
| 228 | ) AS j |
| 229 | FROM rows; |
| 230 | END; |
| 231 | $$; |
| 232 | }}} |
| 233 | |
| 234 | === p_event_update === |
| 235 | {{{ |
| 236 | CREATE OR REPLACE PROCEDURE p_event_update( |
| 237 | IN p_event_id int, |
| 238 | IN p_sql_date date DEFAULT NULL, |
| 239 | IN p_is_root_event boolean DEFAULT NULL, |
| 240 | IN p_event_code varchar(10) DEFAULT NULL, |
| 241 | IN p_goldstein_scale numeric(5,2) DEFAULT NULL, |
| 242 | IN p_num_mentions int DEFAULT NULL, |
| 243 | IN p_num_sources int DEFAULT NULL, |
| 244 | IN p_num_articles int DEFAULT NULL, |
| 245 | IN p_avg_tone numeric(5,2) DEFAULT NULL, |
| 246 | INOUT p_result refcursor DEFAULT NULL |
| 247 | ) |
| 248 | LANGUAGE plpgsql |
| 249 | AS $$ |
| 250 | DECLARE v_exists boolean; |
| 251 | BEGIN |
| 252 | SELECT EXISTS(SELECT 1 FROM events WHERE global_event_id = p_event_id) INTO v_exists; |
| 253 | IF NOT v_exists THEN |
| 254 | IF p_result IS NULL THEN p_result := 'cur_event_update'; END IF; |
| 255 | OPEN p_result FOR |
| 256 | SELECT jsonb_build_object('ok', false, 'error', 'not_found', 'id', p_event_id) AS j; |
| 257 | RETURN; |
| 258 | END IF; |
| 259 | |
| 260 | UPDATE events SET |
| 261 | sql_date = COALESCE(p_sql_date, sql_date), |
| 262 | is_root_event = COALESCE(p_is_root_event, is_root_event), |
| 263 | event_code = COALESCE(p_event_code, event_code), |
| 264 | goldstein_scale= COALESCE(p_goldstein_scale, goldstein_scale), |
| 265 | num_mentions = COALESCE(p_num_mentions, num_mentions), |
| 266 | num_sources = COALESCE(p_num_sources, num_sources), |
| 267 | num_articles = COALESCE(p_num_articles, num_articles), |
| 268 | avg_tone = COALESCE(p_avg_tone, avg_tone), |
| 269 | month_year = CASE WHEN p_sql_date IS NULL THEN month_year ELSE TO_CHAR(p_sql_date,'MMYYYY') END, |
| 270 | year = CASE WHEN p_sql_date IS NULL THEN year ELSE EXTRACT(YEAR FROM p_sql_date)::int END, |
| 271 | fraction_date = CASE WHEN p_sql_date IS NULL THEN fraction_date ELSE (EXTRACT(DOY FROM p_sql_date)::numeric / 365) END |
| 272 | WHERE global_event_id = p_event_id; |
| 273 | |
| 274 | IF p_result IS NULL THEN p_result := 'cur_event_update'; END IF; |
| 275 | OPEN p_result FOR SELECT to_jsonb(e) AS j FROM events e WHERE e.global_event_id = p_event_id; |
| 276 | END; |
| 277 | $$; |
| 278 | }}} |
| 279 | |
| 280 | === p_event_delete === |
| 281 | {{{ |
| 282 | CREATE OR REPLACE PROCEDURE p_event_delete( |
| 283 | IN p_event_id int, |
| 284 | INOUT p_result refcursor DEFAULT NULL |
| 285 | ) |
| 286 | LANGUAGE plpgsql |
| 287 | AS $$ |
| 288 | DECLARE v_ct int; |
| 289 | BEGIN |
| 290 | DELETE FROM events WHERE global_event_id = p_event_id; |
| 291 | GET DIAGNOSTICS v_ct = ROW_COUNT; |
| 292 | |
| 293 | IF p_result IS NULL THEN p_result := 'cur_event_delete'; END IF; |
| 294 | IF v_ct = 0 THEN |
| 295 | OPEN p_result FOR |
| 296 | SELECT jsonb_build_object('ok', false, 'error', 'not_found', 'id', p_event_id) AS j; |
| 297 | ELSE |
| 298 | OPEN p_result FOR |
| 299 | SELECT jsonb_build_object('ok', true, 'deleted_id', p_event_id) AS j; |
| 300 | END IF; |
| 301 | END; |
| 302 | $$; |
| 303 | }}} |
| 304 | |
| 305 | == Заклучок == |
| 306 | |
| 307 | Со оваа комбинација на тригери, трансакициски операции, индекси и складирани процедури, Django апликацијата обезбедува: |
| 308 | * Автоматско ажурирање на агрегирани табели |
| 309 | * Валидација на бизнис правила на податочно ниво |
| 310 | * Оптимизирано пребарување со индекси |
| 311 | * Стандарден JSON излез преку PostgreSQL процедури |