Introduction
I wrote this tiny tool to compensate the limitations of the otherwise perfect iTunes player in reports generation. The program exports your iTunes library data to a Microsoft SQL Server (hence the name – sqlTunes) database which can then be queried using T-SQL. I am going to quickly review the underlying data structure of the iTunes library and then I will list some of the reports you can run on it.
Library Structure
iTunes stores the library data in two files – a proprietary binary file called iTunes Library.itl and its XML counterpart called iTunes Music Library.xml. Both files are located in the My Documents\My Music\iTunes\ folder.
The XML file is nothing more than just a representation of a generic dictionary. First it lists the library information, then the track data, and in the end the playlists. Here is a sample XML:
="1.0"="UTF-8"
<!DOCTYPE plist PUBLIC "-//Apple Computer//DTD PLIST 1.0//EN"
"http://www.apple.com/DTDs/PropertyList-1.0.dtd">
<plist version="1.0">
<dict>
<key>Major Version</key><integer>1</integer>
<key>Minor Version</key><integer>1</integer>
<key>Application Version</key><string>6.0.1</string>
<key>Features</key><integer>1</integer>
<key>Music Folder</key>
<string>file://localhost/C:/Archive/Audio/iTunes/</string>
<key>Library Persistent ID</key>
<string>F8D57E57036B9A4E</string>
<key>Tracks</key>
<dict>
<key>36</key>
<dict>
<key>Track ID</key><integer>36</integer>
<key>Name</key><string>...</string>
<key>Artist</key><string>...</string>
<key>Album</key><string>...</string>
...
</dict>
...
</dict>
<key>Playlists</key>
<array>
...
</array>
</dict>
</plist>
As simple as that! sqlTunes ignores everything except the Tracks section which it reads recursively and fills in the Dictionary<string, object>
object. It then builds INSERT
statements and exports the data to the SQL Server.
SQL Structure
The structure is an exact copy of the library data. The database consists of one table called Track
which is defined as:
CREATE TABLE [dbo].[Track] (
[Track ID] [int] NOT NULL,
[Name] [nvarchar] (200) NULL,
[Artist] [nvarchar] (100) NULL,
[Album] [nvarchar] (100) NULL,
[Grouping] [nvarchar] (100) NULL,
[Genre] [nvarchar] (100) NULL,
[Kind] [nvarchar] (100) NULL,
[Size] [int] NULL,
[Total Time] [int] NULL,
[Track Number] [int] NULL,
[Track Count] [int] NULL,
[Year] [int] NULL,
[Date Modified] [datetime] NULL,
[Date Added] [datetime] NULL,
[Bit Rate] [int] NULL,
[Sample Rate] [int] NULL,
[Comments] [nvarchar] (200) NULL,
[Play Count] [int] NULL,
[Play Date] [bigint] NULL,
[Play Date UTC] [datetime] NULL,
[Rating] [int] NULL,
[Track Type] [nvarchar] (100) NULL,
[Location] [nvarchar] (500) NULL,
[File Folder Count] [int] NULL,
[Library Folder Count] [int] NULL
) ON [PRIMARY]
This is probably not the best example to learn database normalisation but certainly enough to run our reports. sqlTunes will delete and re-create the table on each run. The database must exist, it will not create it.
Reports
And finally, here is the fun part. Let us start with something simple, say we want to know the average bit rate of the entire library:
SELECT CAST(ROUND(AVG(CAST([Bit Rate] AS float)),2) AS varchar)
AS [Average Bit Rate]
FROM Track
Now, let us get something more useful. This query lists your entire album collection:
SELECT DISTINCT Artist, Album, [Year], Genre
FROM Track
ORDER BY Artist, [Year], Album
This is a more correct version, it lists only the full albums. You will need to set the Track Count
values to use it effectively:
SELECT Artist, Album, [Year], Genre
FROM Track
GROUP BY Artist, [Year], Album, Genre
HAVING COUNT(*) = MAX([Track Count])
ORDER BY Artist, [Year], Album
Likewise, this one lists the incomplete albums:
SELECT Artist, [Year], Album, Genre
FROM Track
GROUP BY Artist, [Year], Album, Genre
HAVING COUNT(*) < MAX([Track Count])
ORDER BY Artist, [Year], Album
Want to know the albums without the Track Count
value? Here you go:
SELECT DISTINCT Artist, Album, [Year], Genre
FROM Track
WHERE ISNULL([Track Count],0)=0
ORDER BY Artist, [Year], Album
This one returns all the rated albums sorted by their rating. Handy if you have MP3s but want to update your CD collection:
SELECT Artist, Album, [Year], COUNT(*) AS [Songs Rated],
AVG(CAST(Rating AS float)) AS [Album Rating]
FROM Track
WHERE Rating IS NOT NULL
GROUP BY Artist, Album, [Year]
ORDER BY [Album Rating] DESC, [Songs Rated] DESC
This is the same for artists, can be useful when you are looking for new albums to buy:
SELECT Artist, COUNT(*) AS [Songs Rated], AVG(CAST(Rating AS float)) AS [Artist Rating]
FROM Track
WHERE Rating IS NOT NULL
GROUP BY Artist
ORDER BY [Artist Rating] DESC, [Songs Rated] DESC
This query reveals your genre preferences:
SELECT Genre, AVG(CAST(Rating AS float)) AS [Genre Rating], COUNT(*) AS [Songs Rated]
FROM Track
WHERE Rating IS NOT NULL
GROUP BY Genre
ORDER BY [Genre Rating] DESC, [Songs Rated] DESC
Further Developments
If this program proves to be useful, I will continue developing it in these three directions:
- Adding more reports - Please do post your requests, my imagination is limited but I can speak T-SQL :)
- Enhancing the interface - E.g. run reports directly from sqlTunes.
- Support more databases - Most iTunes users do not have Microsoft SQL Server. A file based database like SQLite or even Access will do the job as well.
License
History
- 2005-11-08: Initial version
- 2008-03-04: iTunes 7 compatibility