@@ -14,23 +14,162 @@ yy.WithSelect.prototype.toString = function () {
1414 s +=
1515 this . withs
1616 . map ( function ( w ) {
17- return w . name + ' AS (' + w . select . toString ( ) + ')' ;
17+ var colStr = '' ;
18+ if ( w . columns ) {
19+ colStr =
20+ '(' +
21+ w . columns
22+ . map ( function ( c ) {
23+ return c . columnid ;
24+ } )
25+ . join ( ', ' ) +
26+ ')' ;
27+ }
28+ return (
29+ ( w . recursive ? 'RECURSIVE ' : '' ) + w . name + colStr + ' AS (' + w . select . toString ( ) + ')'
30+ ) ;
1831 } )
19- . join ( ',' ) + ' ' ;
32+ . join ( ', ' ) + ' ' ;
2033 s += this . select . toString ( ) ;
2134 return s ;
2235} ;
2336
37+ // Execute a recursive CTE
38+ function executeRecursiveCTE ( w , databaseid , params ) {
39+ var maxIterations = alasql . options . maxCteIterations || 1000 ;
40+ var db = alasql . databases [ databaseid ] ;
41+ var tableName = w . name ;
42+
43+ // Create the CTE table
44+ var tb = ( db . tables [ tableName ] = new Table ( {
45+ tableid : tableName ,
46+ } ) ) ;
47+ tb . data = [ ] ;
48+
49+ var select = w . select ;
50+ var anchorSelect , recursiveSelect ;
51+
52+ // Check if this is a UNION ALL structure
53+ if ( select . unionall ) {
54+ // The anchor is the first part, recursive is in unionall
55+ anchorSelect = Object . assign ( { } , select ) ;
56+ delete anchorSelect . unionall ;
57+ recursiveSelect = select . unionall ;
58+ } else if ( select . union ) {
59+ // UNION (without ALL) - less common for recursive CTEs but possible
60+ anchorSelect = Object . assign ( { } , select ) ;
61+ delete anchorSelect . union ;
62+ recursiveSelect = select . union ;
63+ } else {
64+ // No recursive part, just execute once
65+ tb . data = select . execute ( databaseid , params ) ;
66+ if ( w . columns ) {
67+ tb . data = renameColumns ( tb . data , w . columns ) ;
68+ }
69+ return tb . data ;
70+ }
71+
72+ // Determine column names - either from explicit column list or from anchor query
73+ var columnNames ;
74+ if ( w . columns && w . columns . length > 0 ) {
75+ columnNames = w . columns . map ( function ( c ) {
76+ return c . columnid ;
77+ } ) ;
78+ }
79+
80+ // Execute anchor query using ALASQL_DETAILS format to get both data and column metadata in one call
81+ var anchorSelectObj = new yy . Select ( anchorSelect ) ;
82+ anchorSelectObj . modifier = 'ALASQL_DETAILS' ;
83+ var anchorDetails = anchorSelectObj . execute ( databaseid , params ) ;
84+
85+ // Get anchor column names from the query result
86+ var anchorColumnNames = anchorDetails . columns . map ( function ( c ) {
87+ return c . columnid ;
88+ } ) ;
89+
90+ // If explicit column names provided, use them; otherwise use anchor column names
91+ if ( ! columnNames ) {
92+ columnNames = anchorColumnNames ;
93+ }
94+
95+ // Map anchor data to target column names (handles both object format and column renaming)
96+ var anchorData = mapColumnsToNames ( anchorDetails . data , anchorColumnNames , columnNames ) ;
97+ tb . data = anchorData . slice ( ) ;
98+
99+ // Iterate with the recursive part
100+ var newRows = anchorData ;
101+ var allData = anchorData . slice ( ) ;
102+ var iteration = 0 ;
103+
104+ while ( newRows . length > 0 && iteration < maxIterations ) {
105+ iteration ++ ;
106+
107+ // Recreate the CTE table with only the new rows to avoid query caching issues
108+ delete db . tables [ tableName ] ;
109+ tb = db . tables [ tableName ] = new Table ( {
110+ tableid : tableName ,
111+ } ) ;
112+ tb . data = newRows ;
113+
114+ // Execute recursive part using ALASQL_DETAILS format
115+ var recursiveSelectObj = new yy . Select ( recursiveSelect ) ;
116+ recursiveSelectObj . modifier = 'ALASQL_DETAILS' ;
117+ var recursiveDetails = recursiveSelectObj . execute ( databaseid , params ) ;
118+
119+ // Handle empty result
120+ if ( ! recursiveDetails . data || recursiveDetails . data . length === 0 ) {
121+ break ;
122+ }
123+
124+ // Get recursive column names and map to target column names by position
125+ var recursiveColumnNames = recursiveDetails . columns . map ( function ( c ) {
126+ return c . columnid ;
127+ } ) ;
128+ var recursiveData = mapColumnsToNames ( recursiveDetails . data , recursiveColumnNames , columnNames ) ;
129+
130+ // Add new rows to the result
131+ newRows = recursiveData ;
132+ for ( var i = 0 ; i < newRows . length ; i ++ ) {
133+ allData . push ( newRows [ i ] ) ;
134+ }
135+ }
136+
137+ // Set final table data
138+ tb . data = allData ;
139+ return allData ;
140+ }
141+
142+ // Helper function to map data from source column names to target column names by position
143+ function mapColumnsToNames ( data , sourceColumns , targetColumns ) {
144+ return data . map ( function ( row ) {
145+ var newRow = { } ;
146+ for ( var i = 0 ; i < targetColumns . length && i < sourceColumns . length ; i ++ ) {
147+ newRow [ targetColumns [ i ] ] = row [ sourceColumns [ i ] ] ;
148+ }
149+ return newRow ;
150+ } ) ;
151+ }
152+
24153yy . WithSelect . prototype . execute = function ( databaseid , params , cb ) {
25154 var self = this ;
26155 // Create temporary tables
27156 var savedTables = [ ] ;
28157 self . withs . forEach ( function ( w ) {
29158 savedTables . push ( alasql . databases [ databaseid ] . tables [ w . name ] ) ;
30- var tb = ( alasql . databases [ databaseid ] . tables [ w . name ] = new Table ( {
31- tableid : w . name ,
32- } ) ) ;
33- tb . data = w . select . execute ( databaseid , params ) ;
159+
160+ if ( w . recursive ) {
161+ // Execute recursive CTE
162+ executeRecursiveCTE ( w , databaseid , params ) ;
163+ } else {
164+ // Non-recursive CTE - original behavior
165+ var tb = ( alasql . databases [ databaseid ] . tables [ w . name ] = new Table ( {
166+ tableid : w . name ,
167+ } ) ) ;
168+ tb . data = w . select . execute ( databaseid , params ) ;
169+ if ( w . columns ) {
170+ tb . data = renameColumns ( tb . data , w . columns ) ;
171+ }
172+ }
34173 } ) ;
35174
36175 var res = 1 ;
0 commit comments