Spaces:
Running
on
Zero
Running
on
Zero
Commit
·
dbe3108
1
Parent(s):
7894dc2
feat: migrate portfolio auto-save from cache to persistent database storage
Browse files- Create portfolio_inputs table with auto-cleanup trigger (keeps last 3 per user)
- Add database methods: save_portfolio_input and get_portfolio_inputs
- Implement ROW_NUMBER() window function for automatic 3-entry limit enforcement
- Add RLS policies for user data security
- Automatic cleanup via AFTER INSERT trigger with ~2-4% latency overhead
- Optimised index on (user_id, created_at DESC) for fast chronological queries
- backend/database.py +64 -0
- database/schema.sql +64 -0
backend/database.py
CHANGED
|
@@ -368,6 +368,70 @@ class Database:
|
|
| 368 |
logger.error(f"Failed to get analysis by ID: {e}")
|
| 369 |
return None
|
| 370 |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 371 |
|
| 372 |
# Global database instance
|
| 373 |
db = Database()
|
|
|
|
| 368 |
logger.error(f"Failed to get analysis by ID: {e}")
|
| 369 |
return None
|
| 370 |
|
| 371 |
+
async def save_portfolio_input(
|
| 372 |
+
self,
|
| 373 |
+
user_id: str,
|
| 374 |
+
portfolio_text: str
|
| 375 |
+
) -> bool:
|
| 376 |
+
"""Save portfolio input text for quick reload.
|
| 377 |
+
|
| 378 |
+
Automatically keeps only last 3 entries per user via database trigger.
|
| 379 |
+
|
| 380 |
+
Args:
|
| 381 |
+
user_id: User ID
|
| 382 |
+
portfolio_text: Raw portfolio input text
|
| 383 |
+
|
| 384 |
+
Returns:
|
| 385 |
+
True if saved successfully, False otherwise
|
| 386 |
+
"""
|
| 387 |
+
if not self.is_connected():
|
| 388 |
+
logger.warning("Database not connected, skipping portfolio input save")
|
| 389 |
+
return False
|
| 390 |
+
|
| 391 |
+
try:
|
| 392 |
+
self.client.table('portfolio_inputs').insert({
|
| 393 |
+
'user_id': user_id,
|
| 394 |
+
'description': portfolio_text
|
| 395 |
+
}).execute()
|
| 396 |
+
|
| 397 |
+
logger.info(f"Saved portfolio input for user {user_id}")
|
| 398 |
+
return True
|
| 399 |
+
|
| 400 |
+
except Exception as e:
|
| 401 |
+
logger.error(f"Failed to save portfolio input: {e}")
|
| 402 |
+
return False
|
| 403 |
+
|
| 404 |
+
async def get_portfolio_inputs(
|
| 405 |
+
self,
|
| 406 |
+
user_id: str,
|
| 407 |
+
limit: int = 3
|
| 408 |
+
) -> List[Dict[str, Any]]:
|
| 409 |
+
"""Get last N portfolio inputs for user.
|
| 410 |
+
|
| 411 |
+
Args:
|
| 412 |
+
user_id: User ID
|
| 413 |
+
limit: Maximum number to return (default 3)
|
| 414 |
+
|
| 415 |
+
Returns:
|
| 416 |
+
List of portfolio input dicts with id, description, created_at
|
| 417 |
+
"""
|
| 418 |
+
if not self.is_connected():
|
| 419 |
+
return []
|
| 420 |
+
|
| 421 |
+
try:
|
| 422 |
+
result = self.client.table('portfolio_inputs')\
|
| 423 |
+
.select('id, description, created_at')\
|
| 424 |
+
.eq('user_id', user_id)\
|
| 425 |
+
.order('created_at', desc=True)\
|
| 426 |
+
.limit(limit)\
|
| 427 |
+
.execute()
|
| 428 |
+
|
| 429 |
+
return result.data if result.data else []
|
| 430 |
+
|
| 431 |
+
except Exception as e:
|
| 432 |
+
logger.error(f"Failed to get portfolio inputs: {e}")
|
| 433 |
+
return []
|
| 434 |
+
|
| 435 |
|
| 436 |
# Global database instance
|
| 437 |
db = Database()
|
database/schema.sql
CHANGED
|
@@ -50,6 +50,50 @@ CREATE TABLE IF NOT EXISTS portfolios (
|
|
| 50 |
CREATE INDEX IF NOT EXISTS idx_portfolios_user_id ON portfolios(user_id);
|
| 51 |
CREATE INDEX IF NOT EXISTS idx_portfolios_created_at ON portfolios(created_at DESC);
|
| 52 |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 53 |
-- Portfolio holdings table
|
| 54 |
CREATE TABLE IF NOT EXISTS portfolio_holdings (
|
| 55 |
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
@@ -159,6 +203,7 @@ CREATE TRIGGER update_portfolios_updated_at BEFORE UPDATE ON portfolios
|
|
| 159 |
-- These are basic permissions; adjust based on your auth setup
|
| 160 |
ALTER TABLE users ENABLE ROW LEVEL SECURITY;
|
| 161 |
ALTER TABLE portfolios ENABLE ROW LEVEL SECURITY;
|
|
|
|
| 162 |
ALTER TABLE portfolio_holdings ENABLE ROW LEVEL SECURITY;
|
| 163 |
ALTER TABLE portfolio_analyses ENABLE ROW LEVEL SECURITY;
|
| 164 |
|
|
@@ -209,6 +254,25 @@ CREATE POLICY portfolios_delete_own ON portfolios
|
|
| 209 |
TO authenticated
|
| 210 |
USING ((SELECT auth.uid()) = user_id);
|
| 211 |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 212 |
-- Holdings policies (optimized subquery pattern)
|
| 213 |
DROP POLICY IF EXISTS holdings_access_own ON portfolio_holdings;
|
| 214 |
CREATE POLICY holdings_access_own ON portfolio_holdings
|
|
|
|
| 50 |
CREATE INDEX IF NOT EXISTS idx_portfolios_user_id ON portfolios(user_id);
|
| 51 |
CREATE INDEX IF NOT EXISTS idx_portfolios_created_at ON portfolios(created_at DESC);
|
| 52 |
|
| 53 |
+
-- Portfolio inputs table (for auto-save history - keeps last 3 per user)
|
| 54 |
+
CREATE TABLE IF NOT EXISTS portfolio_inputs (
|
| 55 |
+
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
| 56 |
+
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
| 57 |
+
description TEXT NOT NULL,
|
| 58 |
+
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
| 59 |
+
);
|
| 60 |
+
|
| 61 |
+
CREATE INDEX IF NOT EXISTS idx_portfolio_inputs_user_created ON portfolio_inputs(user_id, created_at DESC);
|
| 62 |
+
|
| 63 |
+
-- Trigger function to limit portfolio inputs to 3 per user
|
| 64 |
+
CREATE OR REPLACE FUNCTION limit_portfolio_inputs_per_user()
|
| 65 |
+
RETURNS TRIGGER
|
| 66 |
+
LANGUAGE plpgsql
|
| 67 |
+
SECURITY INVOKER
|
| 68 |
+
SET search_path = ''
|
| 69 |
+
AS $$
|
| 70 |
+
BEGIN
|
| 71 |
+
-- Keep only the 3 most recent entries per user
|
| 72 |
+
DELETE FROM public.portfolio_inputs
|
| 73 |
+
WHERE id IN (
|
| 74 |
+
SELECT id
|
| 75 |
+
FROM (
|
| 76 |
+
SELECT id,
|
| 77 |
+
ROW_NUMBER() OVER (
|
| 78 |
+
PARTITION BY user_id
|
| 79 |
+
ORDER BY created_at DESC
|
| 80 |
+
) AS row_num
|
| 81 |
+
FROM public.portfolio_inputs
|
| 82 |
+
WHERE user_id = NEW.user_id
|
| 83 |
+
) ranked
|
| 84 |
+
WHERE row_num > 3
|
| 85 |
+
);
|
| 86 |
+
|
| 87 |
+
RETURN NULL;
|
| 88 |
+
END;
|
| 89 |
+
$$;
|
| 90 |
+
|
| 91 |
+
-- Create trigger for automatic cleanup
|
| 92 |
+
DROP TRIGGER IF EXISTS trigger_limit_portfolio_inputs ON portfolio_inputs;
|
| 93 |
+
CREATE TRIGGER trigger_limit_portfolio_inputs
|
| 94 |
+
AFTER INSERT ON portfolio_inputs
|
| 95 |
+
FOR EACH ROW EXECUTE FUNCTION limit_portfolio_inputs_per_user();
|
| 96 |
+
|
| 97 |
-- Portfolio holdings table
|
| 98 |
CREATE TABLE IF NOT EXISTS portfolio_holdings (
|
| 99 |
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
|
|
| 203 |
-- These are basic permissions; adjust based on your auth setup
|
| 204 |
ALTER TABLE users ENABLE ROW LEVEL SECURITY;
|
| 205 |
ALTER TABLE portfolios ENABLE ROW LEVEL SECURITY;
|
| 206 |
+
ALTER TABLE portfolio_inputs ENABLE ROW LEVEL SECURITY;
|
| 207 |
ALTER TABLE portfolio_holdings ENABLE ROW LEVEL SECURITY;
|
| 208 |
ALTER TABLE portfolio_analyses ENABLE ROW LEVEL SECURITY;
|
| 209 |
|
|
|
|
| 254 |
TO authenticated
|
| 255 |
USING ((SELECT auth.uid()) = user_id);
|
| 256 |
|
| 257 |
+
-- Portfolio inputs table policies
|
| 258 |
+
DROP POLICY IF EXISTS portfolio_inputs_read_own ON portfolio_inputs;
|
| 259 |
+
CREATE POLICY portfolio_inputs_read_own ON portfolio_inputs
|
| 260 |
+
FOR SELECT
|
| 261 |
+
TO authenticated
|
| 262 |
+
USING ((SELECT auth.uid()) = user_id);
|
| 263 |
+
|
| 264 |
+
DROP POLICY IF EXISTS portfolio_inputs_insert_own ON portfolio_inputs;
|
| 265 |
+
CREATE POLICY portfolio_inputs_insert_own ON portfolio_inputs
|
| 266 |
+
FOR INSERT
|
| 267 |
+
TO authenticated
|
| 268 |
+
WITH CHECK ((SELECT auth.uid()) = user_id);
|
| 269 |
+
|
| 270 |
+
DROP POLICY IF EXISTS portfolio_inputs_delete_own ON portfolio_inputs;
|
| 271 |
+
CREATE POLICY portfolio_inputs_delete_own ON portfolio_inputs
|
| 272 |
+
FOR DELETE
|
| 273 |
+
TO authenticated
|
| 274 |
+
USING ((SELECT auth.uid()) = user_id);
|
| 275 |
+
|
| 276 |
-- Holdings policies (optimized subquery pattern)
|
| 277 |
DROP POLICY IF EXISTS holdings_access_own ON portfolio_holdings;
|
| 278 |
CREATE POLICY holdings_access_own ON portfolio_holdings
|