I might try later to cut down the number of queries (i.e., attempt the
almost impossible), but I agree that a single SQL statement here looks
pretty tough.
Sometimes, though, you can't beat the convenience of
a single SQL statement.
Actually, you're going to kick yourself when I tell you, but it is
easy to do in a single statement (and no subqueries!) if you use the
standard trick of a table of unique integers named Sequence (limited
as appropriate) and Jet's MID() expression to find the folder-
delimiting characters:
SELECT DISTINCT MID(T1.fldPath, 1, S1.seq) AS node
FROM Folders AS T1, Sequence AS S1
WHERE MID(T1.fldPath, S1.seq, 1) = '\';
Here's some SQL to recreate the OP's scenario and demo the above
suggestion:
Sub ParseOnNodes()
Kill Environ$("temp") & "\DropMe.mdb"
Dim cat
Set cat = CreateObject("ADOX.Catalog")
With cat
..Create _
"Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=" & _
Environ$("temp") & "\DropMe.mdb"
With .ActiveConnection
Dim Sql As String
Sql = _
"CREATE TABLE Folders (fldPath" & _
" VARCHAR(255) NOT NULL)"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\folderA\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\folderA\')"
..Execute Sql
Sql = _
"INSERT INTO Folders (fldPath)" & _
" VALUES ('c:\folderA\folderB\folderC\folder1\folderB\')"
..Execute Sql
Sql = _
"CREATE TABLE Sequence (seq INTEGER" & _
" NOT NULL UNIQUE)"
..Execute Sql
Sql = _
"INSERT INTO Sequence (seq)" & vbCr & "SELECT" & _
" Units.nbr + Tens.nbr + Hundreds.nbr" & _
" AS seq " & vbCr & "FROM (SELECT DISTINCT" & _
" nbr FROM (SELECT DISTINCT 0 AS" & _
" nbr FROM Folders UNION ALL SELECT" & _
" DISTINCT 1 FROM Folders UNION" & _
" ALL SELECT DISTINCT 2 FROM Folders" & _
" UNION ALL SELECT DISTINCT 3 FROM" & _
" Folders UNION ALL SELECT DISTINCT" & _
" 4 FROM Folders UNION ALL SELECT" & _
" DISTINCT 5 FROM Folders UNION" & _
" ALL SELECT DISTINCT 6 FROM Folders" & _
" UNION ALL SELECT DISTINCT 7 FROM" & _
" Folders UNION ALL SELECT DISTINCT" & _
" 8 FROM Folders UNION ALL SELECT" & _
" DISTINCT 9 FROM Folders) AS Digits)" & _
" AS Units, (SELECT DISTINCT nbr" & _
" * 10 AS nbr FROM (SELECT DISTINCT" & _
" 0 AS nbr FROM Folders UNION ALL" & _
" SELECT DISTINCT 1 FROM Folders"
Sql = Sql & _
" UNION ALL SELECT DISTINCT 2 FROM" & _
" Folders UNION ALL SELECT DISTINCT" & _
" 3 FROM Folders UNION ALL SELECT" & _
" DISTINCT 4 FROM Folders UNION" & _
" ALL SELECT DISTINCT 5 FROM Folders" & _
" UNION ALL SELECT DISTINCT 6 FROM" & _
" Folders UNION ALL SELECT DISTINCT" & _
" 7 FROM Folders UNION ALL SELECT" & _
" DISTINCT 8 FROM Folders UNION" & _
" ALL SELECT DISTINCT 9 FROM Folders)" & _
" AS Digits) AS Tens, (SELECT DISTINCT" & _
" nbr * 100 AS nbr FROM (SELECT" & _
" DISTINCT 0 AS nbr FROM Folders" & _
" UNION ALL SELECT DISTINCT 1 FROM" & _
" Folders UNION ALL SELECT DISTINCT" & _
" 2 FROM Folders UNION ALL SELECT" & _
" DISTINCT 3 FROM Folders UNION" & _
" ALL SELECT DISTINCT 4 FROM Folders" & _
" UNION ALL SELECT DISTINCT 5 FROM" & _
" Folders UNION ALL SELECT DISTINCT"
Sql = Sql & _
" 6 FROM Folders UNION ALL SELECT" & _
" DISTINCT 7 FROM Folders UNION" & _
" ALL SELECT DISTINCT 8 FROM Folders" & _
" UNION ALL SELECT DISTINCT 9 FROM" & _
" Folders) AS Digits) AS Hundreds" & vbCr & "WHERE" & _
" Units.nbr + Tens.nbr + Hundreds.nbr" & _
" BETWEEN 1 AND 255"
..Execute Sql
Sql = _
"SELECT DISTINCT MID(T1.fldPath," & _
" 1, S1.seq) AS node" & vbCr & "FROM Folders" & _
" AS T1" & vbCr & "INNER JOIN Sequence AS" & _
" S1" & vbCr & "ON (S1.seq BETWEEN 1 AND LEN(T1.fldPath))" & vbCr &
"WHERE" & _
" MID(T1.fldPath, S1.seq, 1) =" & _
" '\'"
Dim rs
Set rs = .Execute(Sql)
MsgBox rs.GetString
End With
Set .ActiveConnection = Nothing
End With
End Sub
Jamie.
--