1515from  mysql .connector  import  CharacterSet , errorcode 
1616from  mysql .connector .abstracts  import  MySQLConnectionAbstract 
1717from  mysql .connector .types  import  RowItemType 
18+ from  sqlglot  import  exp , parse_one 
19+ from  sqlglot .errors  import  ParseError 
1820from  tqdm  import  tqdm , trange 
1921
2022
@@ -120,6 +122,8 @@ def __init__(self, **kwargs: Unpack[MySQLtoSQLiteParams]) -> None:
120122
121123        self ._quiet  =  bool (kwargs .get ("quiet" , False ))
122124
125+         self ._views_as_views  =  bool (kwargs .get ("views_as_views" , True ))
126+ 
123127        self ._sqlite_strict  =  bool (kwargs .get ("sqlite_strict" , False ))
124128
125129        self ._logger  =  self ._setup_logger (log_file = kwargs .get ("log_file" ) or  None , quiet = self ._quiet )
@@ -637,6 +641,7 @@ def _create_table(self, table_name: str, attempting_reconnect: bool = False) ->
637641                if  not  attempting_reconnect :
638642                    self ._logger .warning ("Connection to MySQL server lost.\n Attempting to reconnect." )
639643                    self ._create_table (table_name , True )
644+                     return 
640645                else :
641646                    self ._logger .warning ("Connection to MySQL server lost.\n Reconnection attempt aborted." )
642647                    raise 
@@ -650,6 +655,130 @@ def _create_table(self, table_name: str, attempting_reconnect: bool = False) ->
650655            self ._logger .error ("SQLite failed creating table %s: %s" , table_name , err )
651656            raise 
652657
658+     @staticmethod  
659+     def  _mysql_viewdef_to_sqlite (
660+         view_select_sql : str ,
661+         view_name : str ,
662+         schema_name : t .Optional [str ] =  None ,
663+         keep_schema : bool  =  False ,
664+     ) ->  str :
665+         """ 
666+         Convert a MySQL VIEW_DEFINITION (a SELECT ...) to a SQLite CREATE VIEW statement. 
667+ 
668+         If keep_schema is False and schema_name is provided, strip qualifiers like `example`.table. 
669+         If keep_schema is True, you must ATTACH the SQLite database as that schema name before using the view. 
670+         """ 
671+         # Normalize whitespace and avoid double semicolons in output 
672+         cleaned_sql  =  view_select_sql .strip ().rstrip (";" )
673+ 
674+         try :
675+             tree  =  parse_one (cleaned_sql , read = "mysql" )
676+         except  (ParseError , ValueError , Exception ):  # pylint: disable=W0718 
677+             # Fallback: return a basic CREATE VIEW using the original SELECT 
678+             return  f'CREATE VIEW IF NOT EXISTS "{ view_name }  " AS\n { cleaned_sql }  ;' 
679+ 
680+         if  not  keep_schema  and  schema_name :
681+             # Remove schema qualifiers that match schema_name 
682+             for  tbl  in  tree .find_all (exp .Table ):
683+                 db  =  tbl .args .get ("db" )
684+                 if  db  and  db .name .strip ('`"' ) ==  schema_name :
685+                     tbl .set ("db" , None )
686+ 
687+         sqlite_select  =  tree .sql (dialect = "sqlite" )
688+         return  f'CREATE VIEW IF NOT EXISTS "{ view_name }  " AS\n { sqlite_select }  ;' 
689+ 
690+     def  _build_create_view_sql (self , view_name : str ) ->  str :
691+         """Build a CREATE VIEW statement for SQLite from a MySQL VIEW definition.""" 
692+         # Try to obtain the view definition from information_schema.VIEWS 
693+         definition : t .Optional [str ] =  None 
694+         try :
695+             self ._mysql_cur_dict .execute (
696+                 """ 
697+                 SELECT VIEW_DEFINITION AS `definition` 
698+                 FROM information_schema.VIEWS 
699+                 WHERE TABLE_SCHEMA = %s 
700+                   AND TABLE_NAME = %s 
701+                 """ ,
702+                 (self ._mysql_database , view_name ),
703+             )
704+             row : t .Optional [t .Dict [str , RowItemType ]] =  self ._mysql_cur_dict .fetchone ()
705+             if  row  is  not   None  and  row .get ("definition" ) is  not   None :
706+                 val  =  row ["definition" ]
707+                 if  isinstance (val , bytes ):
708+                     try :
709+                         definition  =  val .decode ()
710+                     except  UnicodeDecodeError :
711+                         definition  =  str (val )
712+                 else :
713+                     definition  =  t .cast (str , val )
714+         except  mysql .connector .Error :
715+             # Fall back to SHOW CREATE VIEW below 
716+             definition  =  None 
717+ 
718+         if  not  definition :
719+             # Fallback: use SHOW CREATE VIEW and extract the SELECT part 
720+             try :
721+                 # Escape backticks in the MySQL view name for safe interpolation 
722+                 safe_view_name  =  view_name .replace ("`" , "``" )
723+                 self ._mysql_cur .execute (f"SHOW CREATE VIEW `{ safe_view_name }  `" )
724+                 res  =  self ._mysql_cur .fetchone ()
725+                 if  res  and  len (res ) >=  2 :
726+                     create_stmt  =  res [1 ]
727+                     if  isinstance (create_stmt , bytes ):
728+                         try :
729+                             create_stmt_str  =  create_stmt .decode ()
730+                         except  UnicodeDecodeError :
731+                             create_stmt_str  =  str (create_stmt )
732+                     else :
733+                         create_stmt_str  =  t .cast (str , create_stmt )
734+                     # Extract the SELECT ... part after AS (supporting newlines) 
735+                     m  =  re .search (r"\bAS\b\s*(.*)$" , create_stmt_str , re .IGNORECASE  |  re .DOTALL )
736+                     if  m :
737+                         definition  =  m .group (1 ).strip ().rstrip (";" )
738+                     else :
739+                         # As a last resort, try to use the full statement replacing the prefix 
740+                         # Not ideal, but better than failing outright 
741+                         idx  =  create_stmt_str .upper ().find (" AS " )
742+                         if  idx  !=  - 1 :
743+                             definition  =  create_stmt_str [idx  +  4  :].strip ().rstrip (";" )
744+             except  mysql .connector .Error :
745+                 pass 
746+ 
747+         if  not  definition :
748+             raise  sqlite3 .Error (f"Unable to fetch definition for MySQL view '{ view_name }  '" )
749+ 
750+         return  self ._mysql_viewdef_to_sqlite (
751+             view_name = view_name ,
752+             view_select_sql = definition ,
753+             schema_name = self ._mysql_database ,
754+         )
755+ 
756+     def  _create_view (self , view_name : str , attempting_reconnect : bool  =  False ) ->  None :
757+         try :
758+             if  attempting_reconnect :
759+                 self ._mysql .reconnect ()
760+             sql  =  self ._build_create_view_sql (view_name )
761+             self ._sqlite_cur .execute (sql )
762+             self ._sqlite .commit ()
763+         except  mysql .connector .Error  as  err :
764+             if  err .errno  ==  errorcode .CR_SERVER_LOST :
765+                 if  not  attempting_reconnect :
766+                     self ._logger .warning ("Connection to MySQL server lost.\n Attempting to reconnect." )
767+                     self ._create_view (view_name , True )
768+                     return 
769+                 else :
770+                     self ._logger .warning ("Connection to MySQL server lost.\n Reconnection attempt aborted." )
771+                     raise 
772+             self ._logger .error (
773+                 "MySQL failed reading view definition from view %s: %s" ,
774+                 view_name ,
775+                 err ,
776+             )
777+             raise 
778+         except  sqlite3 .Error  as  err :
779+             self ._logger .error ("SQLite failed creating view %s: %s" , view_name , err )
780+             raise 
781+ 
653782    def  _transfer_table_data (
654783        self , table_name : str , sql : str , total_records : int  =  0 , attempting_reconnect : bool  =  False 
655784    ) ->  None :
@@ -693,6 +822,7 @@ def _transfer_table_data(
693822                        total_records = total_records ,
694823                        attempting_reconnect = True ,
695824                    )
825+                     return 
696826                else :
697827                    self ._logger .warning ("Connection to MySQL server lost.\n Reconnection attempt aborted." )
698828                    raise 
@@ -720,7 +850,7 @@ def transfer(self) -> None:
720850
721851            self ._mysql_cur_prepared .execute (
722852                """ 
723-                 SELECT TABLE_NAME 
853+                 SELECT TABLE_NAME, TABLE_TYPE  
724854                FROM information_schema.TABLES 
725855                WHERE TABLE_SCHEMA = SCHEMA() 
726856                AND TABLE_NAME {exclude} IN ({placeholders}) 
@@ -730,25 +860,49 @@ def transfer(self) -> None:
730860                ),
731861                specific_tables ,
732862            )
733-             tables : t .Iterable [RowItemType ] =  (row [0 ] for  row  in  self ._mysql_cur_prepared .fetchall ())
863+             tables : t .Iterable [t .Tuple [str , str ]] =  (
864+                 (
865+                     str (row [0 ].decode () if  isinstance (row [0 ], (bytes , bytearray )) else  row [0 ]),
866+                     str (row [1 ].decode () if  isinstance (row [1 ], (bytes , bytearray )) else  row [1 ]),
867+                 )
868+                 for  row  in  self ._mysql_cur_prepared .fetchall ()
869+             )
734870        else :
735871            # transfer all tables 
736872            self ._mysql_cur .execute (
737873                """ 
738-                 SELECT TABLE_NAME 
874+                 SELECT TABLE_NAME, TABLE_TYPE  
739875                FROM information_schema.TABLES 
740876                WHERE TABLE_SCHEMA = SCHEMA() 
741877            """ 
742878            )
743-             tables  =  (row [0 ].decode () for  row  in  self ._mysql_cur .fetchall ())  # type: ignore[union-attr] 
879+ 
880+             def  _coerce_row (row : t .Any ) ->  t .Tuple [str , str ]:
881+                 try :
882+                     # Row like (name, type) 
883+                     name  =  row [0 ].decode () if  isinstance (row [0 ], (bytes , bytearray )) else  row [0 ]
884+                     ttype  =  (
885+                         row [1 ].decode ()
886+                         if  (isinstance (row , (list , tuple )) and  len (row ) >  1  and  isinstance (row [1 ], (bytes , bytearray )))
887+                         else  (row [1 ] if  (isinstance (row , (list , tuple )) and  len (row ) >  1 ) else  "BASE TABLE" )
888+                     )
889+                     return  str (name ), str (ttype )
890+                 except  (TypeError , IndexError , UnicodeDecodeError ):
891+                     # Fallback: treat as a single value name when row is not a 2-tuple or decoding fails 
892+                     name  =  row .decode () if  isinstance (row , (bytes , bytearray )) else  str (row )
893+                     return  name , "BASE TABLE" 
894+ 
895+             tables  =  (_coerce_row (row ) for  row  in  self ._mysql_cur .fetchall ())
744896
745897        try :
746898            # turn off foreign key checking in SQLite while transferring data 
747899            self ._sqlite_cur .execute ("PRAGMA foreign_keys=OFF" )
748900
749-             for  table_name  in  tables :
901+             for  table_name ,  table_type  in  tables :
750902                if  isinstance (table_name , bytes ):
751903                    table_name  =  table_name .decode ()
904+                 if  isinstance (table_type , bytes ):
905+                     table_type  =  table_type .decode ()
752906
753907                self ._logger .info (
754908                    "%s%sTransferring table %s" ,
@@ -761,10 +915,13 @@ def transfer(self) -> None:
761915                self ._current_chunk_number  =  0 
762916
763917                if  not  self ._without_tables :
764-                     # create the table 
765-                     self ._create_table (table_name )  # type: ignore[arg-type] 
918+                     # create the table or view 
919+                     if  table_type  ==  "VIEW"  and  self ._views_as_views :
920+                         self ._create_view (table_name )  # type: ignore[arg-type] 
921+                     else :
922+                         self ._create_table (table_name )  # type: ignore[arg-type] 
766923
767-                 if  not  self ._without_data :
924+                 if  not  self ._without_data   and   not  ( table_type   ==   "VIEW"   and   self . _views_as_views ) :
768925                    # get the size of the data 
769926                    if  self ._limit_rows  >  0 :
770927                        # limit to the requested number of rows 
0 commit comments