postgres.py 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342
  1. import io
  2. import logging
  3. from datetime import datetime
  4. from io import BytesIO
  5. from typing import BinaryIO, Optional
  6. from uuid import UUID
  7. from zipfile import ZipFile
  8. import asyncpg
  9. from fastapi import HTTPException
  10. from core.base import FileConfig, FileProvider, R2RException
  11. logger = logging.getLogger()
  12. class PostgresFileProvider(FileProvider):
  13. """PostgreSQL implementation of the FileProvider."""
  14. def __init__(
  15. self,
  16. config: FileConfig,
  17. project_name: str,
  18. connection_manager, # PostgresConnectionManager
  19. ):
  20. super().__init__(config)
  21. self.table_name = "files"
  22. self.project_name = project_name
  23. self.connection_manager = connection_manager
  24. def _get_table_name(self, base_name: str) -> str:
  25. return f"{self.project_name}.{base_name}"
  26. async def initialize(self) -> None:
  27. """Create the necessary tables for file storage."""
  28. query = f"""
  29. CREATE TABLE IF NOT EXISTS {self._get_table_name(self.table_name)} (
  30. document_id UUID PRIMARY KEY,
  31. name TEXT NOT NULL,
  32. oid OID NOT NULL,
  33. size BIGINT NOT NULL,
  34. type TEXT,
  35. created_at TIMESTAMPTZ DEFAULT NOW(),
  36. updated_at TIMESTAMPTZ DEFAULT NOW()
  37. );
  38. -- Create trigger for updating the updated_at timestamp
  39. CREATE OR REPLACE FUNCTION {self.project_name}.update_files_updated_at()
  40. RETURNS TRIGGER AS $$
  41. BEGIN
  42. NEW.updated_at = CURRENT_TIMESTAMP;
  43. RETURN NEW;
  44. END;
  45. $$ LANGUAGE plpgsql;
  46. DROP TRIGGER IF EXISTS update_files_updated_at
  47. ON {self._get_table_name(self.table_name)};
  48. CREATE TRIGGER update_files_updated_at
  49. BEFORE UPDATE ON {self._get_table_name(self.table_name)}
  50. FOR EACH ROW
  51. EXECUTE FUNCTION {self.project_name}.update_files_updated_at();
  52. """
  53. await self.connection_manager.execute_query(query)
  54. async def upsert_file(
  55. self,
  56. document_id: UUID,
  57. file_name: str,
  58. file_oid: int,
  59. file_size: int,
  60. file_type: Optional[str] = None,
  61. ) -> None:
  62. """Add or update a file entry in storage."""
  63. query = f"""
  64. INSERT INTO {self._get_table_name(self.table_name)}
  65. (document_id, name, oid, size, type)
  66. VALUES ($1, $2, $3, $4, $5)
  67. ON CONFLICT (document_id) DO UPDATE SET
  68. name = EXCLUDED.name,
  69. oid = EXCLUDED.oid,
  70. size = EXCLUDED.size,
  71. type = EXCLUDED.type,
  72. updated_at = NOW();
  73. """
  74. await self.connection_manager.execute_query(
  75. query, [document_id, file_name, file_oid, file_size, file_type]
  76. )
  77. async def store_file(
  78. self,
  79. document_id: UUID,
  80. file_name: str,
  81. file_content: io.BytesIO,
  82. file_type: Optional[str] = None,
  83. ) -> None:
  84. """Store a new file in the database."""
  85. size = file_content.getbuffer().nbytes
  86. async with (
  87. self.connection_manager.pool.get_connection() as conn # type: ignore
  88. ):
  89. async with conn.transaction():
  90. oid = await conn.fetchval("SELECT lo_create(0)")
  91. await self._write_lobject(conn, oid, file_content)
  92. await self.upsert_file(
  93. document_id, file_name, oid, size, file_type
  94. )
  95. async def _write_lobject(
  96. self, conn, oid: int, file_content: io.BytesIO
  97. ) -> None:
  98. """Write content to a large object."""
  99. lobject = await conn.fetchval("SELECT lo_open($1, $2)", oid, 0x20000)
  100. try:
  101. chunk_size = 8192 # 8 KB chunks
  102. while True:
  103. if chunk := file_content.read(chunk_size):
  104. await conn.execute(
  105. "SELECT lowrite($1, $2)", lobject, chunk
  106. )
  107. else:
  108. break
  109. await conn.execute("SELECT lo_close($1)", lobject)
  110. except Exception as e:
  111. await conn.execute("SELECT lo_unlink($1)", oid)
  112. raise HTTPException(
  113. status_code=500,
  114. detail=f"Failed to write to large object: {e}",
  115. ) from e
  116. async def retrieve_file(
  117. self, document_id: UUID
  118. ) -> Optional[tuple[str, BinaryIO, int]]:
  119. """Retrieve a file from storage."""
  120. query = f"""
  121. SELECT name, oid, size
  122. FROM {self._get_table_name(self.table_name)}
  123. WHERE document_id = $1
  124. """
  125. result = await self.connection_manager.fetchrow_query(
  126. query, [document_id]
  127. )
  128. if not result:
  129. raise R2RException(
  130. status_code=404,
  131. message=f"File for document {document_id} not found",
  132. )
  133. file_name, oid, size = (
  134. result["name"],
  135. result["oid"],
  136. result["size"],
  137. )
  138. async with self.connection_manager.pool.get_connection() as conn: # type: ignore
  139. file_content = await self._read_lobject(conn, oid)
  140. return file_name, io.BytesIO(file_content), size
  141. async def retrieve_files_as_zip(
  142. self,
  143. document_ids: Optional[list[UUID]] = None,
  144. start_date: Optional[datetime] = None,
  145. end_date: Optional[datetime] = None,
  146. ) -> tuple[str, BinaryIO, int]:
  147. """Retrieve multiple files and return them as a zip file."""
  148. query = f"""
  149. SELECT document_id, name, oid, size
  150. FROM {self._get_table_name(self.table_name)}
  151. WHERE 1=1
  152. """
  153. params: list = []
  154. if document_ids:
  155. query += f" AND document_id = ANY(${len(params) + 1})"
  156. params.append([str(doc_id) for doc_id in document_ids])
  157. if start_date:
  158. query += f" AND created_at >= ${len(params) + 1}"
  159. params.append(start_date)
  160. if end_date:
  161. query += f" AND created_at <= ${len(params) + 1}"
  162. params.append(end_date)
  163. query += " ORDER BY created_at DESC"
  164. results = await self.connection_manager.fetch_query(query, params)
  165. if not results:
  166. raise R2RException(
  167. status_code=404,
  168. message="No files found matching the specified criteria",
  169. )
  170. zip_buffer = BytesIO()
  171. total_size = 0
  172. async with self.connection_manager.pool.get_connection() as conn: # type: ignore
  173. with ZipFile(zip_buffer, "w") as zip_file:
  174. for record in results:
  175. file_content = await self._read_lobject(
  176. conn, record["oid"]
  177. )
  178. zip_file.writestr(record["name"], file_content)
  179. total_size += record["size"]
  180. zip_buffer.seek(0)
  181. timestamp = datetime.now().strftime("%Y%m%d_%H%M%S")
  182. zip_filename = f"files_export_{timestamp}.zip"
  183. return zip_filename, zip_buffer, zip_buffer.getbuffer().nbytes
  184. async def _read_lobject(self, conn, oid: int) -> bytes:
  185. """Read content from a large object."""
  186. file_data = io.BytesIO()
  187. chunk_size = 8192
  188. async with conn.transaction():
  189. try:
  190. lo_exists = await conn.fetchval(
  191. "SELECT EXISTS(SELECT 1 FROM pg_catalog.pg_largeobject_metadata WHERE oid = $1);",
  192. oid,
  193. )
  194. if not lo_exists:
  195. raise R2RException(
  196. status_code=404,
  197. message=f"Large object {oid} not found.",
  198. )
  199. lobject = await conn.fetchval(
  200. "SELECT lo_open($1, 262144)", oid
  201. )
  202. if lobject is None:
  203. raise R2RException(
  204. status_code=404,
  205. message=f"Failed to open large object {oid}.",
  206. )
  207. while True:
  208. chunk = await conn.fetchval(
  209. "SELECT loread($1, $2)", lobject, chunk_size
  210. )
  211. if not chunk:
  212. break
  213. file_data.write(chunk)
  214. except asyncpg.exceptions.UndefinedObjectError:
  215. raise R2RException(
  216. status_code=404,
  217. message=f"Failed to read large object {oid}",
  218. ) from None
  219. finally:
  220. await conn.execute("SELECT lo_close($1)", lobject)
  221. return file_data.getvalue()
  222. async def delete_file(self, document_id: UUID) -> bool:
  223. """Delete a file from storage."""
  224. query = f"""
  225. SELECT oid FROM {self._get_table_name(self.table_name)}
  226. WHERE document_id = $1
  227. """
  228. async with self.connection_manager.pool.get_connection() as conn: # type: ignore
  229. async with conn.transaction():
  230. oid = await conn.fetchval(query, document_id)
  231. if not oid:
  232. raise R2RException(
  233. status_code=404,
  234. message=f"File for document {document_id} not found",
  235. )
  236. await self._delete_lobject(conn, oid)
  237. delete_query = f"""
  238. DELETE FROM {self._get_table_name(self.table_name)}
  239. WHERE document_id = $1
  240. """
  241. await conn.execute(delete_query, document_id)
  242. return True
  243. async def _delete_lobject(self, conn, oid: int) -> None:
  244. """Delete a large object."""
  245. await conn.execute("SELECT lo_unlink($1)", oid)
  246. async def get_files_overview(
  247. self,
  248. offset: int,
  249. limit: int,
  250. filter_document_ids: Optional[list[UUID]] = None,
  251. filter_file_names: Optional[list[str]] = None,
  252. ) -> list[dict]:
  253. """Get an overview of stored files."""
  254. conditions = []
  255. params: list[str | list[str] | int] = []
  256. query = f"""
  257. SELECT document_id, name, oid, size, type, created_at, updated_at
  258. FROM {self._get_table_name(self.table_name)}
  259. """
  260. if filter_document_ids:
  261. conditions.append(f"document_id = ANY(${len(params) + 1})")
  262. params.append([str(doc_id) for doc_id in filter_document_ids])
  263. if filter_file_names:
  264. conditions.append(f"name = ANY(${len(params) + 1})")
  265. params.append(filter_file_names)
  266. if conditions:
  267. query += " WHERE " + " AND ".join(conditions)
  268. query += f" ORDER BY created_at DESC OFFSET ${len(params) + 1} LIMIT ${len(params) + 2}"
  269. params.extend([offset, limit])
  270. results = await self.connection_manager.fetch_query(query, params)
  271. if not results:
  272. raise R2RException(
  273. status_code=404,
  274. message="No files found with the given filters",
  275. )
  276. return [
  277. {
  278. "document_id": row["document_id"],
  279. "file_name": row["name"],
  280. "file_oid": row["oid"],
  281. "file_size": row["size"],
  282. "file_type": row["type"],
  283. "created_at": row["created_at"],
  284. "updated_at": row["updated_at"],
  285. }
  286. for row in results
  287. ]