|
1 | | -# Module Description: Parses missing ROWID values from the SMS.db, presents the number of missing rows, and provides timestamps for data rows before and after the missing data |
2 | | -# Author: @SQL_McGee |
3 | | -# Date: 2023-03-20 |
4 | | -# Artifact version: 0.0.1 |
5 | | -# Requirements: none |
6 | | - |
7 | | -# This query was the product of research completed by James McGee, Metadata Forensics, LLC, for "Lagging for the Win", published by Belkasoft |
8 | | -# https://belkasoft.com/lagging-for-win |
9 | | - |
10 | | -import sqlite3 |
11 | | -import textwrap |
| 1 | +__artifacts_v2__ = { |
| 2 | + "SMS_Missing_ROWIDs": { |
| 3 | + "name": "SMS - Missing ROWIDs", |
| 4 | + "description": "Parses missing ROWID values from the SMS.db, presents the number of missing rows, and provides timestamps for data rows before and after the missing data", |
| 5 | + "author": "@SQLMcGee for Metadata Forensics, LLC", |
| 6 | + "creation_date": "2023-03-20", |
| 7 | + "last_update_date": "2025-11-13", |
| 8 | + "requirements": "none", |
| 9 | + "category": "SMS & iMessage", |
| 10 | + "notes": "This query was the product of research completed by James McGee, Metadata Forensics, LLC, for 'Lagging for the Win', published by Belkasoft https://belkasoft.com/lagging-for-win, updated upon further research", |
| 11 | + "paths": ("*SMS/sms*"), |
| 12 | + "output_types": "standard", |
| 13 | + "artifact_icon": "message-circle" |
| 14 | + } |
| 15 | +} |
12 | 16 |
|
13 | | -from packaging import version |
14 | | -from scripts.artifact_report import ArtifactHtmlReport |
15 | | -from scripts.ilapfuncs import logfunc, logdevinfo, tsv, timeline, is_platform_windows, open_sqlite_db_readonly |
| 17 | +from scripts.ilapfuncs import artifact_processor, get_sqlite_db_records, convert_cocoa_core_data_ts_to_utc |
16 | 18 |
|
17 | | -def get_SMS(files_found, report_folder, seeker, wrap_text, timezone_offset): |
18 | | - |
19 | | - sms = '' |
| 19 | +@artifact_processor |
| 20 | +def SMS_Missing_ROWIDs(context): |
| 21 | + """ See artifact description """ |
| 22 | + data_source = context.get_source_file_path('sms.db') |
20 | 23 |
|
21 | | - for file_found in files_found: |
22 | | - file_name = str(file_found) |
23 | | - if file_name.endswith('sms.db'): |
24 | | - sms = str(file_found) |
25 | | - source_file_sms = file_found.replace(seeker.data_folder, '') |
26 | | - |
27 | | - db = open_sqlite_db_readonly(sms) |
| 24 | + data_list = [] |
28 | 25 |
|
29 | | - cursor = db.cursor() |
30 | | - |
31 | | - cursor.execute(''' |
| 26 | + query = ''' |
| 27 | + WITH LastROWID AS ( |
| 28 | + SELECT seq AS last_rowid |
| 29 | + FROM sqlite_sequence |
| 30 | + WHERE sqlite_sequence.name = 'message' |
| 31 | + ) |
32 | 32 | SELECT * FROM ( |
33 | | - SELECT |
34 | | - CASE -- This column is the same as the very first column but obtaining timestamp instead of the ROWID value. A CASE statement is used to capture data whether using seconds since Jan 1, 1970 or microseconds since Jan 1, 1970 |
35 | | - WHEN length(DATE) = 18 |
36 | | - THEN LAG(DATETIME(DATE/1000000000 + 978307200, 'UNIXEPOCH'),1) OVER (ORDER BY ROWID) |
37 | | - WHEN length(DATE) = 9 |
38 | | - THEN LAG(DATETIME(DATE + 978307200, 'UNIXEPOCH'),1) OVER (ORDER BY ROWID) |
39 | | - END AS "Beginning Timestamp", |
40 | | - CASE -- Finally, this last column obtains the timestamp for the row following the missing row |
41 | | - WHEN length(DATE) = 18 |
42 | | - THEN DATETIME(DATE/1000000000 + 978307200, 'UNIXEPOCH') |
43 | | - WHEN length(DATE) = 9 |
44 | | - THEN DATETIME(DATE + 978307200, 'UNIXEPOCH') |
45 | | - END AS "Ending Timestamp", |
46 | | - LAG (ROWID,1) OVER (ORDER BY ROWID) AS "Previous ROWID", -- This column uses the LAG function to obtain the ROWID value prior to a missing row |
47 | | - ROWID AS "ROWID", -- This column obtains the ROWID value following the missing row |
48 | | - (ROWID - (LAG (ROWID,1) OVER (ORDER BY ROWID)) - 1) AS "Number of Missing Rows" -- This column is a subtraction of the first two columns, minus one additional value, to obtain the number of missing rows |
49 | | - FROM message) list |
50 | | - WHERE ROWID - "Previous ROWID" > 1; |
51 | | - ''') |
| 33 | + SELECT * FROM ( |
| 34 | + SELECT |
| 35 | + LAG(message.date,1) OVER (ORDER BY ROWID) AS "Beginning Timestamp", |
| 36 | + message.date AS "Ending Timestamp", |
| 37 | + LAG (guid,1) OVER (ORDER BY ROWID) AS "Previous guid", |
| 38 | + guid AS "guid", |
| 39 | + LAG (ROWID,1) OVER (ORDER BY ROWID) AS "Previous ROWID", |
| 40 | + ROWID AS "ROWID", |
| 41 | + (ROWID - (LAG (ROWID,1) OVER (ORDER BY ROWID)) - 1) AS "Number of Missing Rows" |
| 42 | + FROM message) list |
| 43 | + WHERE ROWID - "Previous ROWID" > 1 |
| 44 | +
|
| 45 | + UNION ALL |
| 46 | +
|
| 47 | + SELECT |
| 48 | + CASE |
| 49 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 50 | + THEN MAX(message.date) |
| 51 | + END AS "Beginning Timestamp", |
| 52 | + CASE |
| 53 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 54 | + THEN "Time of Extraction" |
| 55 | + END AS "Ending Timestamp", |
| 56 | + CASE |
| 57 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 58 | + THEN guid |
| 59 | + END AS "Previous guid", |
| 60 | + CASE |
| 61 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 62 | + THEN "Unknown" |
| 63 | + END AS "guid", |
| 64 | + CASE |
| 65 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 66 | + THEN MAX(ROWID) |
| 67 | + END AS "Previous ROWID", |
| 68 | + CASE |
| 69 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 70 | + THEN (SELECT last_rowid FROM LastROWID) |
| 71 | + END AS "ROWID", |
| 72 | + CASE |
| 73 | + WHEN message.ROWID != (SELECT last_rowid FROM LastROWID) |
| 74 | + THEN ((SELECT last_rowid FROM LastROWID) - message.ROWID) |
| 75 | + END AS "Number of Missing Rows" |
| 76 | + FROM message) |
| 77 | + WHERE "ROWID" IS NOT NULL;''' |
52 | 78 |
|
53 | | - all_rows = cursor.fetchall() |
54 | | - usageentries = len(all_rows) |
55 | | - if usageentries > 0: |
56 | | - data_list = [] |
57 | | - for row in all_rows: |
58 | | - data_list.append( |
59 | | - (row[0], row[1], row[2], row[3], row[4])) |
| 79 | + data_headers = (('Beginning Timestamp', 'datetime'), ('Ending Timestamp', 'datetime'), 'Previous guid', 'guid', 'Previous ROWID', 'ROWID', 'Number of Missing Rows') |
| 80 | + |
| 81 | + db_records = get_sqlite_db_records(data_source, query) |
| 82 | + |
| 83 | + def fix_ts(val): |
| 84 | + if not isinstance(val, (int, float)): |
| 85 | + return val |
60 | 86 |
|
61 | | - report = ArtifactHtmlReport('SMS - Missing ROWIDs') |
62 | | - report.start_artifact_report(report_folder, 'SMS - Missing ROWIDs') |
63 | | - report.add_script() |
64 | | - data_headers = ( |
65 | | - 'Beginning Timestamp', 'Ending Timestamp','Previous ROWID', 'ROWID', 'Number of Missing Rows') |
66 | | - report.write_artifact_data_table(data_headers, data_list, sms) |
67 | | - report.end_artifact_report() |
| 87 | + digits = len(str(abs(int(val)))) |
68 | 88 |
|
69 | | - tsvname = 'SMS - Missing ROWIDs' |
70 | | - tsv(report_folder, data_headers, data_list, tsvname) |
| 89 | + if digits > 17: |
| 90 | + val = val / 1e9 |
71 | 91 |
|
72 | | - tlactivity = 'SMS - Missing ROWIDs' |
73 | | - timeline(report_folder, tlactivity, data_list, data_headers) |
74 | | - else: |
75 | | - logfunc('No data available in SMS - Missing ROWIDs') |
76 | | - |
77 | | -__artifacts__ = { |
78 | | - "SMS Missing ROWIDs": ( |
79 | | - "SMS & iMessage", |
80 | | - ('*/mobile/Library/SMS/sms*'), |
81 | | - get_SMS) |
82 | | -} |
| 92 | + elif digits > 14: |
| 93 | + val = val / 1e6 |
| 94 | + |
| 95 | + return convert_cocoa_core_data_ts_to_utc(val) |
| 96 | + |
| 97 | + for record in db_records: |
| 98 | + start_raw = record[0] |
| 99 | + end_raw = record[1] |
| 100 | + |
| 101 | + start_timestamp = fix_ts(start_raw) |
| 102 | + end_timestamp = fix_ts(end_raw) |
| 103 | + |
| 104 | + data_list.append( |
| 105 | + (start_timestamp, end_timestamp, record[2], record[3], record[4], record[5], record[6]) |
| 106 | + ) |
| 107 | + |
| 108 | + return data_headers, data_list, data_source |
0 commit comments