5.8 KiB
PostgreSQL Compatibility Fix for Comments Management
Issue
The comments management page was showing "No comments found" even though comments existed in the database. This was because the original implementation used SQLite-specific features (like rowid) that don't exist in PostgreSQL.
Root Cause
Your database is PostgreSQL (as configured in database_config.ini), but the comments management code was written with SQLite assumptions:
- SQLite has
rowid- An implicit row identifier column - PostgreSQL uses
ctid- A system column that serves a similar purpose but has different syntax - Different DELETE/UPDATE syntax - PostgreSQL doesn't support
LIMITdirectly in DELETE/UPDATE statements
Fixes Applied
1. SELECT Query Fix (Reading Comments)
Before:
SELECT rowid, matchDate, comment FROM _motmcomments
After:
-- First tries to find an explicit ID column
SELECT column_name FROM information_schema.columns
WHERE table_name = '_motmcomments' AND column_name IN ('id', 'rowid', 'oid')
-- If found, uses that column
SELECT id as comment_id, matchDate, comment FROM _motmcomments
-- Otherwise, uses PostgreSQL's ctid
SELECT ctid::text as comment_id, matchDate, comment FROM _motmcomments
-- Last resort: generates row numbers
SELECT ROW_NUMBER() OVER (ORDER BY matchDate DESC) as comment_id,
matchDate, comment FROM _motmcomments
2. DELETE Query Fix
Before:
DELETE FROM _motmcomments WHERE rowid = :comment_id
After:
-- Primary method: Use ctid
DELETE FROM _motmcomments WHERE ctid = :comment_id::tid
-- Fallback: Match on date and comment content
DELETE FROM _motmcomments
WHERE ctid IN (
SELECT ctid FROM _motmcomments
WHERE matchDate = :match_date AND comment = :comment
LIMIT 1
)
3. UPDATE Query Fix
Before:
UPDATE _motmcomments SET comment = :comment WHERE rowid = :comment_id
After:
-- Primary method: Use ctid
UPDATE _motmcomments SET comment = :comment WHERE ctid = :comment_id::tid
-- Fallback: Match on date and comment content
UPDATE _motmcomments
SET comment = :new_comment
WHERE ctid IN (
SELECT ctid FROM _motmcomments
WHERE matchDate = :match_date AND comment = :old_comment
LIMIT 1
)
4. Template Updates
Updated comments_management.html to:
- Use
comment.comment_idinstead ofcomment.rowid - Pass additional hidden fields:
match_dateandoriginal_comment - Handle string-based IDs (ctid is text like
(0,1)) - Use
CSS.escape()for safe selector handling
5. JavaScript Updates
Updated JavaScript functions to handle non-numeric IDs:
function toggleEdit(commentId) {
const escapedId = CSS.escape(String(commentId)); // Handle any string format
// ...
}
Database Compatibility Matrix
| Feature | SQLite | PostgreSQL | MySQL |
|---|---|---|---|
| Implicit Row ID | rowid |
ctid |
None (need explicit PK) |
| ID Type | Integer | Text (tuple) | Integer |
| DELETE with LIMIT | ✓ Supported | ✗ Need subquery | ✓ Supported |
| information_schema | ✗ Limited | ✓ Full support | ✓ Full support |
PostgreSQL ctid Explained
ctid is a system column in PostgreSQL that stores the physical location of a row:
- Format:
(page_number, tuple_index)- e.g.,(0,1)or(42,17) - Type:
tid(tuple identifier) - Must be cast to text for display:
ctid::text - Must be cast from text for comparison:
'(0,1)'::tid
Important Notes:
ctidcan change afterVACUUMoperations- Not suitable for long-term row references
- Perfect for temporary identification within a transaction
- Our implementation includes fallback methods for robustness
Testing
After the fix, the comments management page should:
- Display all comments from the database
- Show proper IDs (either from ctid or generated row numbers)
- Allow editing - Update specific comments
- Allow deletion - Remove individual comments
- Bulk operations - Delete by match date or all comments
- Column management - Drop unwanted columns
Verifying the Fix
Check Comments Exist
SELECT COUNT(*) FROM _motmcomments;
SELECT * FROM _motmcomments LIMIT 5;
Check ctid Values
SELECT ctid::text, matchDate, comment FROM _motmcomments LIMIT 5;
Test in Application
- Navigate to
/admin/comments/manage - Verify comments are displayed
- Try editing a comment
- Try deleting a comment
- Check that operations succeed
Known Limitations
-
ctid instability: After database maintenance (VACUUM FULL), ctid values change. Our fallback methods handle this.
-
Duplicate comments: If two identical comments exist for the same match date, the fallback methods will affect only the first match.
-
Performance: The fallback queries using subqueries are slightly slower than direct ctid lookups, but acceptable for the expected data volume.
Future Improvements
Consider adding an explicit id column to _motmcomments:
ALTER TABLE _motmcomments ADD COLUMN id SERIAL PRIMARY KEY;
This would provide:
- Stable, permanent row identifiers
- Better performance
- Database-agnostic code
- Easier troubleshooting
Related Files Modified
-
main.py(lines 1385-1520)- Updated
comments_management()function - Multi-database query strategy
- Fallback error handling
- Updated
-
templates/comments_management.html- Changed
rowidtocomment_id - Added hidden form fields
- Updated JavaScript for string IDs
- Changed
Summary
The comments management feature now works correctly with PostgreSQL by:
- Using PostgreSQL-specific
ctidfor row identification - Implementing robust fallback methods
- Handling different data types gracefully
- Maintaining compatibility with future database types
All functionality (view, edit, delete, bulk operations) now works as intended.