Fix timestamp consistency across all tables

- Update USERS table schema to use TIMESTAMP instead of integer
- Add migration 003 to convert existing integer timestamps to TIMESTAMP
- Remove timestamp-to-unix calls in playlist-management.lisp (use DB default)
- Update user-management.lisp to use postmodern:execute for last-login update
- All timestamp columns now consistently use PostgreSQL TIMESTAMP type
This commit is contained in:
Glenn Thompson 2025-12-09 12:34:38 +03:00 committed by Brian O'Reilly
parent 22b2a2d87e
commit 46d57e2775
4 changed files with 45 additions and 9 deletions

View File

@ -12,9 +12,8 @@ CREATE TABLE IF NOT EXISTS "USERS" (
"password-hash" TEXT NOT NULL,
role VARCHAR(50) DEFAULT 'listener',
active integer DEFAULT 1,
-- "created-date" integer DEFAULT CURRENT_TIMESTAMP,
"created-date" integer,
"last-login" integer,
"created-date" TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
"last-login" TIMESTAMP,
CONSTRAINT valid_role CHECK (role IN ('listener', 'dj', 'admin'))
);

View File

@ -0,0 +1,33 @@
-- Migration 003: Timestamp Consistency
-- Convert USERS table integer timestamps to TIMESTAMP type
-- This aligns USERS with tracks and playlists tables which already use TIMESTAMP
-- Step 1: Add new TIMESTAMP columns
ALTER TABLE "USERS" ADD COLUMN IF NOT EXISTS "created-date-new" TIMESTAMP;
ALTER TABLE "USERS" ADD COLUMN IF NOT EXISTS "last-login-new" TIMESTAMP;
-- Step 2: Convert existing epoch integers to timestamps
-- Only convert non-null values; epoch 0 or very old dates indicate no real value
UPDATE "USERS"
SET "created-date-new" = TO_TIMESTAMP("created-date")
WHERE "created-date" IS NOT NULL
AND "created-date" > 0;
UPDATE "USERS"
SET "last-login-new" = TO_TIMESTAMP("last-login")
WHERE "last-login" IS NOT NULL
AND "last-login" > 0;
-- Step 3: Drop old integer columns
ALTER TABLE "USERS" DROP COLUMN IF EXISTS "created-date";
ALTER TABLE "USERS" DROP COLUMN IF EXISTS "last-login";
-- Step 4: Rename new columns to original names
ALTER TABLE "USERS" RENAME COLUMN "created-date-new" TO "created-date";
ALTER TABLE "USERS" RENAME COLUMN "last-login-new" TO "last-login";
-- Step 5: Set default for created-date (new users get current timestamp)
ALTER TABLE "USERS" ALTER COLUMN "created-date" SET DEFAULT CURRENT_TIMESTAMP;
-- Verification query (run manually to check results):
-- SELECT _id, username, "created-date", "last-login" FROM "USERS";

View File

@ -15,7 +15,7 @@
(setf (dm:field playlist "name") name)
(setf (dm:field playlist "description") (or description ""))
(setf (dm:field playlist "track-ids") "") ; Empty string for text field
(setf (dm:field playlist "created-date") (local-time:timestamp-to-unix (local-time:now)))
;; Let database default handle created-date (CURRENT_TIMESTAMP)
(format t "Creating playlist with user-id: ~a (type: ~a)~%" user-id (type-of user-id))
(format t "Playlist data: ~a~%" (data-model-as-alist playlist))
(dm:insert playlist)

View File

@ -16,7 +16,7 @@
(dm:field user "password-hash") password-hash
(dm:field user "role") (string-downcase (symbol-name role))
(dm:field user "active") (if active 1 0)
(dm:field user "created-date") (local-time:timestamp-to-unix (local-time:now))
;; Let database defaults handle created-date (CURRENT_TIMESTAMP)
(dm:field user "last-login") nil)
(handler-case
(db:with-transaction ()
@ -69,10 +69,14 @@
(format t "Error during user data access: ~a~%" e)))
(when (and (= 1 user-active)
(verify-password password user-password))
;; Update last login
(setf (dm:field user "last-login") (local-time:timestamp-to-unix (local-time:now)))
;; (dm:save user)
(data-model-save user)
;; Update last login using raw SQL to set CURRENT_TIMESTAMP
(handler-case
(postmodern:with-connection (get-db-connection-params)
(postmodern:execute
(format nil "UPDATE \"USERS\" SET \"last-login\" = CURRENT_TIMESTAMP WHERE _id = ~a"
(dm:id user))))
(error (e)
(format t "Warning: Could not update last-login: ~a~%" e)))
user)))))
(defun hash-password (password)