diff --git a/app/api/user_db_api.py b/app/api/user_db_api.py index f837dc3..cd1dbf2 100644 --- a/app/api/user_db_api.py +++ b/app/api/user_db_api.py @@ -7,7 +7,7 @@ from app.core.response import ResponseMessage from app.core.status import CommonCode from app.schemas.user_db.db_profile_model import DBProfileInfo, UpdateOrCreateDBProfile -from app.schemas.user_db.result_model import ColumnInfo, DBProfile, TableInfo +from app.schemas.user_db.result_model import ColumnInfo, DBDetail, DBProfile, TableInfo from app.services.user_db_service import UserDbService, user_db_service user_db_service_dependency = Depends(lambda: user_db_service) @@ -156,3 +156,18 @@ def find_all_schema_info( full_schema_info = service.get_full_schema_info(db_info) return ResponseMessage.success(value=full_schema_info, code=CommonCode.SUCCESS) + + +@router.get( + "/find/hierarchical-schema/{profile_id}", + response_model=ResponseMessage[DBDetail], + summary="특정 DB의 전체 스키마의 계층적 상세 정보 조회", + description="스키마, 테이블, 컬럼, 제약조건, 인덱스를 포함한 모든 스키마 정보를 계층 구조로 반환합니다.", +) +def find_hierarchical_schema_info( + profile_id: str, service: UserDbService = user_db_service_dependency +) -> ResponseMessage[DBDetail]: + db_info = service.find_profile(profile_id) + hierarchical_schema_info = service.get_hierarchical_schema_info(db_info) + + return ResponseMessage.success(value=hierarchical_schema_info, code=CommonCode.SUCCESS) diff --git a/app/repository/user_db_repository.py b/app/repository/user_db_repository.py index eb3421b..f886eb8 100644 --- a/app/repository/user_db_repository.py +++ b/app/repository/user_db_repository.py @@ -316,30 +316,31 @@ def _find_columns_for_oracle(self, cursor: Any, schema_name: str, table_name: st c.data_scale, c.column_id as ordinal_position FROM - user_tab_columns c + all_tab_columns c LEFT JOIN - user_col_comments cc ON c.table_name = cc.table_name AND c.column_name = cc.column_name + all_col_comments cc ON c.owner = cc.owner AND c.table_name = cc.table_name AND c.column_name = cc.column_name LEFT JOIN ( SELECT + acc.owner, acc.table_name, acc.column_name, ac.constraint_type FROM - user_constraints ac + all_constraints ac JOIN - user_cons_columns acc ON ac.constraint_name = acc.constraint_name + all_cons_columns acc ON ac.owner = acc.owner AND ac.constraint_name = acc.constraint_name WHERE ac.constraint_type = 'P' - ) cons ON c.table_name = cons.table_name AND c.column_name = cons.column_name + ) cons ON c.owner = cons.owner AND c.table_name = cons.table_name AND c.column_name = cons.column_name WHERE - c.table_name = :table_name + c.owner = :owner AND c.table_name = :table_name ORDER BY c.column_id """ try: - logging.info(f"Executing find_columns_for_oracle for table: {table_name.upper()}") - cursor.execute(sql, {"table_name": table_name.upper()}) + logging.info(f"Executing find_columns_for_oracle for table: {schema_name.upper()}.{table_name.upper()}") + cursor.execute(sql, {"owner": schema_name.upper(), "table_name": table_name.upper()}) columns_raw = cursor.fetchall() logging.info(f"Found {len(columns_raw)} raw columns for table: {table_name.upper()}") @@ -556,21 +557,21 @@ def _find_constraints_for_oracle(self, cursor: Any, schema_name: str, table_name r_acc.column_name AS referenced_column, ac.delete_rule FROM - user_constraints ac + all_constraints ac JOIN - user_cons_columns acc ON ac.constraint_name = acc.constraint_name AND ac.table_name = acc.table_name + all_cons_columns acc ON ac.owner = acc.owner AND ac.constraint_name = acc.constraint_name AND ac.table_name = acc.table_name LEFT JOIN - user_constraints r_ac ON ac.r_constraint_name = r_ac.constraint_name + all_constraints r_ac ON ac.r_owner = r_ac.owner AND ac.r_constraint_name = r_ac.constraint_name LEFT JOIN - user_cons_columns r_acc ON ac.r_constraint_name = r_acc.constraint_name AND acc.position = r_acc.position + all_cons_columns r_acc ON ac.r_owner = r_acc.owner AND ac.r_constraint_name = r_acc.constraint_name AND acc.position = r_acc.position WHERE - ac.table_name = :table_name + ac.owner = :owner AND ac.table_name = :table_name ORDER BY ac.constraint_name, acc.position """ try: - logging.info(f"Executing find_constraints_for_oracle for table: {table_name.upper()}") - cursor.execute(sql, {"table_name": table_name.upper()}) + logging.info(f"Executing find_constraints_for_oracle for table: {schema_name.upper()}.{table_name.upper()}") + cursor.execute(sql, {"owner": schema_name.upper(), "table_name": table_name.upper()}) raw_constraints = cursor.fetchall() logging.info(f"Found {len(raw_constraints)} raw constraints for table: {table_name.upper()}") @@ -719,20 +720,20 @@ def _find_indexes_for_oracle(self, cursor: Any, schema_name: str, table_name: st i.uniqueness, ic.column_name FROM - user_indexes i + all_indexes i JOIN - user_ind_columns ic ON i.index_name = ic.index_name + all_ind_columns ic ON i.owner = ic.index_owner AND i.index_name = ic.index_name LEFT JOIN - user_constraints ac ON i.index_name = ac.constraint_name AND ac.constraint_type = 'P' + all_constraints ac ON i.owner = ac.owner AND i.index_name = ac.constraint_name AND ac.constraint_type = 'P' WHERE - i.table_name = :table_name + i.owner = :owner AND i.table_name = :table_name AND ac.constraint_name IS NULL ORDER BY i.index_name, ic.column_position """ try: - logging.info(f"Executing find_indexes_for_oracle for table: {table_name.upper()}") - cursor.execute(sql, {"table_name": table_name.upper()}) + logging.info(f"Executing find_indexes_for_oracle for table: {schema_name.upper()}.{table_name.upper()}") + cursor.execute(sql, {"owner": schema_name.upper(), "table_name": table_name.upper()}) raw_indexes = cursor.fetchall() logging.info(f"Found {len(raw_indexes)} raw indexes for table: {table_name.upper()}") diff --git a/app/schemas/user_db/result_model.py b/app/schemas/user_db/result_model.py index d2a5b2a..9af5550 100644 --- a/app/schemas/user_db/result_model.py +++ b/app/schemas/user_db/result_model.py @@ -106,3 +106,23 @@ class TableListResult(BasicResult): class ColumnListResult(BasicResult): columns: list[ColumnInfo] = Field([], description="컬럼 정보 목록") + + +# ───────────────────────────── +# 계층적 스키마 조회를 위한 모델 +# ───────────────────────────── + + +class SchemaDetail(BaseModel): + """계층적 조회에서 스키마 정보를 담는 모델 (테이블 포함)""" + + schema_name: str = Field(..., description="스키마 이름") + tables: list[TableInfo] = Field([], description="테이블 목록") + + +class DBDetail(BaseModel): + """계층적 조회에서 DB 정보를 담는 모델 (스키마 포함)""" + + db_name: str | None = Field(None, description="데이터베이스 이름") + db_type: str = Field(..., description="데이터베이스 종류") + schemas: list[SchemaDetail] = Field([], description="스키마 목록") diff --git a/app/services/user_db_service.py b/app/services/user_db_service.py index e139ced..3a6aef9 100644 --- a/app/services/user_db_service.py +++ b/app/services/user_db_service.py @@ -19,6 +19,8 @@ BasicResult, ChangeProfileResult, ColumnListResult, + DBDetail, + SchemaDetail, SchemaInfoResult, TableInfo, TableListResult, @@ -217,6 +219,67 @@ def get_full_schema_info( logging.error("An unexpected error occurred in get_full_schema_info", exc_info=True) raise APIException(CommonCode.FAIL) from e + def get_hierarchical_schema_info( + self, db_info: AllDBProfileInfo, repository: UserDbRepository = user_db_repository + ) -> DBDetail: + """ + DB 프로필 정보를 받아 해당 데이터베이스의 전체 스키마 정보를 + 계층적인 구조 (스키마 -> 테이블 -> 컬럼 등)로 조회하여 반환합니다. + """ + logging.info(f"Starting hierarchical schema scan for db_profile: {db_info.id}") + try: + driver_module = self._get_driver_module(db_info.type) + connect_kwargs = self._prepare_connection_args(db_info) + + schemas_result = repository.find_schemas( + driver_module, self._get_schema_query(db_info.type), **connect_kwargs + ) + + if not schemas_result.is_successful: + raise APIException(CommonCode.FAIL_FIND_SCHEMAS) + + schemas_to_scan = schemas_result.schemas + + # For sqlite, schemas might be empty, default to 'main' + if db_info.type.lower() == "sqlite" and not schemas_to_scan: + schemas_to_scan = ["main"] + + schema_details = [] + for schema_name in sorted(schemas_to_scan): + # For Oracle, schema names are uppercase. + effective_schema_name = schema_name + if db_info.type.lower() == "oracle": + effective_schema_name = schema_name.upper() + + tables_result = repository.find_tables( + driver_module, self._get_table_query(db_info.type), effective_schema_name, **connect_kwargs + ) + logging.info( + f"Found {len(tables_result.tables)} tables in schema '{effective_schema_name}': {tables_result.tables}" + ) + + if not tables_result.is_successful: + logging.warning(f"Failed to find tables for schema '{effective_schema_name}'. Skipping.") + continue + + table_details = [] + for table_name in tables_result.tables: + table_info = self._get_table_details( + driver_module, db_info, effective_schema_name, table_name, connect_kwargs, repository + ) + table_details.append(table_info) + + if table_details: + schema_details.append(SchemaDetail(schema_name=schema_name, tables=table_details)) + + logging.info(f"Finished hierarchical schema scan. Total schemas found: {len(schema_details)}.") + return DBDetail(db_name=db_info.name, db_type=db_info.type, schemas=schema_details) + except APIException: + raise + except Exception as e: + logging.error("An unexpected error occurred in get_hierarchical_schema_info", exc_info=True) + raise APIException(CommonCode.FAIL) from e + def _get_schemas_to_scan( self, db_info: AllDBProfileInfo, @@ -400,7 +463,7 @@ def _get_table_query(self, db_type: str, for_all_schemas: bool = False) -> str | WHERE table_type = 'BASE TABLE' AND table_schema = %s """ elif db_type == "oracle": - return "SELECT table_name FROM user_tables" + return "SELECT table_name FROM all_tables WHERE owner = :owner" elif db_type == "sqlite": return "SELECT name FROM sqlite_master WHERE type='table'" return None