Ticket #1919: mfd.diff

File mfd.diff, 20.8 KB (added by Colin Guthrie <mythtv@…>, 14 years ago)

Jochen's MFD Patch.

  • mfd/plugins/mmusic/mmusic.cpp

     
    7777    //  This is a "magic" number signifying what we want to see
    7878    //
    7979   
    80     desired_database_version = "1005";
     80    desired_database_version = "1006";
    8181
    8282    //
    8383    //  Initialize our container and set things up for a clean slate
     
    526526   
    527527    MSqlQuery query(MSqlQuery::InitCon());
    528528   
    529     query.exec("SELECT intid, filename FROM musicmetadata ;");
     529    query.exec("SELECT song_id, filename FROM music_songs ;");
    530530   
    531531    if(query.isActive())
    532532    {
     
    544544
    545545                    ++count;
    546546                    MSqlQuery delete_query(MSqlQuery::InitCon());
    547                     delete_query.prepare("DELETE FROM musicmetadata WHERE intid = ?");
     547                    delete_query.prepare("DELETE FROM music_songs WHERE song_id = ?");
    548548                    delete_query.bindValue(0, query.value(0).toUInt());
    549549                    delete_query.exec();
    550550                    log(QString("removed item %1 (\"%2\") from the database")
     
    556556    }
    557557    else
    558558    {
    559         warning("something wrong with your musicmetadata table");
     559        warning("something wrong with your music_songs table");
    560560    }
    561561   
    562562    if(count > 0)
     
    638638   
    639639    MSqlQuery query(MSqlQuery::InitCon());
    640640   
    641     query.exec("SELECT COUNT(filename) FROM musicmetadata;");
     641    query.exec("SELECT COUNT(filename) FROM music_songs;");
    642642   
    643643    if(!query.isActive())
    644644    {
    645645        if(!sent_musicmetadata_table_warning)
    646646        {
    647             warning("cannot get data from a table called musicmetadata");
     647            warning("cannot get data from a table called music_songs");
    648648            sent_musicmetadata_table_warning = true;
    649649        }
    650650        return false;
    651651       
    652652    }
    653653   
    654     query.exec("SELECT COUNT(playlistid) FROM musicplaylist ");
     654    query.exec("SELECT COUNT(playlist_id) FROM music_saved_playlists ");
    655655
    656656    if(!query.isActive())
    657657    {
    658658        if(!sent_playlist_table_warning)
    659659        {
    660             warning("cannot get data from a table called musisplaylist");
     660            warning("cannot get data from a table called music_saved_playlists");
    661661            sent_playlist_table_warning = true;
    662662        }
    663663        return false;
     
    977977
    978978    MSqlQuery query(MSqlQuery::InitCon());
    979979
    980     query.prepare("SELECT intid, artist, album, title, genre, "
    981                   "year, tracknum, length, rating, "
    982                   "lastplay, playcount, mythdigest, size, date_added, "
    983                   "date_modified, format, description, comment, "
    984                   "compilation, composer, disc_count, disc_number, "
    985                   "track_count, start_time, stop_time, eq_preset, "
    986                   "relative_volume, sample_rate, bpm "
    987                   "FROM musicmetadata WHERE filename = ? ;");
     980    query.prepare("SELECT music_songs.song_id, music_artists.artist_name, "
     981                  "music_albums.album_name, music_songs.name, "
     982                  "music_genres.genre, music_songs.year, "
     983                  "music_songs.track, music_songs.length, "
     984                  "music_songs.rating, music_songs.lastplay, "
     985                  "music_songs.numplays, music_songs.mythdigest,"
     986                  "music_songs.size, music_songs.date_entered, "
     987                  "music_songs.date_modified, music_songs.format, "
     988                  "music_songs.description, music_songs.comment, "
     989                  "music_songs.compilation, music_comp_artists.artist_name AS composer, "
     990                  "music_songs.disc_count, music_songs.disc_number, "
     991                  "music_songs.track_count, music_songs.start_time, "
     992                  "music_songs.stop_time, music_songs.eq_preset, "
     993                  "music_songs.relative_volume, music_songs.bitrate, "
     994                  "music_songs.bpm "
     995                  "FROM music_songs "
     996                  "LEFT JOIN music_artists ON music_songs.artist_id=music_artists.artist_id "
     997                  "LEFT JOIN music_artists AS music_comp_artists ON music_songs.compilationartist_id=music_comp_artists.artist_id "
     998                  "LEFT JOIN music_albums ON music_songs.album_id=music_albums.album_id "
     999                  "LEFT JOIN music_genres ON music_songs.genre_id=music_genres.genre_id "
     1000                  "WHERE filename = ? ;");
    9881001
    9891002    query.bindValue(0, sqlfilename.utf8());
    990    
     1003
    9911004    query.exec();
    9921005
    9931006    if (query.isActive())
     
    11981211       
    11991212        MSqlQuery query(MSqlQuery::InitCon());
    12001213
    1201         query.prepare("INSERT INTO musicmetadata (filename, mythdigest) "
     1214        query.prepare("INSERT INTO music_songs(filename, mythdigest) "
    12021215                      "values ( ? , ?)");
    12031216
    12041217        query.bindValue(0, sqlfilename.utf8());
     
    12131226            return NULL;
    12141227        }
    12151228       
    1216         query.prepare("SELECT intid FROM musicmetadata "
     1229        query.prepare("SELECT song_id FROM music_songs "
    12171230                               "WHERE mythdigest = ? ;");
    12181231        query.bindValue(0, new_item->getMythDigest());
    12191232        query.exec();
     
    13221335
    13231336    MSqlQuery query(MSqlQuery::InitCon());
    13241337
    1325     query.prepare("UPDATE musicmetadata SET "
    1326                   "title = ? , "
    1327                   "artist = ? , "
    1328                   "album = ? , "
    1329                   "genre = ? , "
     1338
     1339//Genrecheck
     1340//Albumcheck
     1341//Artist
     1342    int ArtistID;
     1343    query.prepare("SELECT music_artists.artist_id FROM music_artists "
     1344                  " WHERE (((music_artists.artist_name)=:ARTIST));");
     1345    query.bindValue(":ARTIST", an_item->getArtist().utf8());
     1346    query.exec();
     1347//    cout << query.executedQuery() << endl;
     1348    if (query.size() > 0)
     1349        {
     1350        query.next();
     1351        ArtistID = query.value(0).toInt();
     1352        }
     1353    else
     1354        {
     1355        query.prepare("INSERT INTO music_artists (artist_name) VALUES (:ARTIST);");
     1356        query.bindValue(":ARTIST", an_item->getArtist().utf8());
     1357        query.exec();
     1358//      cout << query.executedQuery() << endl;
     1359        query.prepare("SELECT music_artists.artist_id FROM music_artists "
     1360                  " WHERE (((music_artists.artist_name)=:ARTIST));");
     1361        query.bindValue(":ARTIST", an_item->getArtist().utf8());
     1362        query.exec();
     1363//      cout << query.executedQuery() << endl;
     1364        query.next();
     1365        ArtistID = query.value(0).toInt();     
     1366        }
     1367
     1368//Compilation Artist   
     1369    int CoArtistID;
     1370    query.prepare("SELECT music_artists.artist_id FROM music_artists "
     1371                  " WHERE (((music_artists.artist_name)=:ARTIST));");
     1372    query.bindValue(":ARTIST", an_item->getComposer().utf8());
     1373    query.exec();
     1374//    cout << query.executedQuery() << endl;
     1375    if (query.size() > 0)
     1376        {
     1377        query.next();
     1378        CoArtistID = query.value(0).toInt();
     1379        }
     1380    else
     1381        {
     1382        query.prepare("INSERT INTO music_artists (artist_name) VALUES (:ARTIST);");
     1383        query.bindValue(":ARTIST", an_item->getComposer().utf8());
     1384        query.exec();
     1385//      cout << query.executedQuery() << endl;
     1386        query.prepare("SELECT music_artists.artist_id FROM music_artists "
     1387                  " WHERE (((music_artists.artist_name)=:ARTIST));");
     1388        query.bindValue(":ARTIST", an_item->getComposer().utf8());
     1389        query.exec();
     1390//      cout << query.executedQuery() << endl;
     1391        query.next();
     1392        CoArtistID = query.value(0).toInt();   
     1393        }
     1394
     1395//Album
     1396    int AlbumID;
     1397    query.prepare("SELECT music_albums.album_id FROM music_albums "
     1398                  " WHERE (((music_albums.album_name)=:ALBUM));");
     1399    query.bindValue(":ALBUM", an_item->getAlbum().utf8());
     1400    query.exec();
     1401//    cout << query.executedQuery() << endl;
     1402    if (query.size() > 0)
     1403        {
     1404        query.next();
     1405        AlbumID = query.value(0).toInt();
     1406        }
     1407    else
     1408        {
     1409        query.prepare("INSERT INTO music_albums (album_name) VALUES (:ALBUM);");
     1410        query.bindValue(":ALBUM", an_item->getAlbum().utf8());
     1411        query.exec();
     1412//      cout << query.executedQuery() << endl;
     1413       
     1414        query.prepare("SELECT music_albums.album_id FROM music_albums "
     1415                  " WHERE (((music_albums.album_name)=:ALBUM));");
     1416        query.bindValue(":ALBUM", an_item->getAlbum().utf8());
     1417        query.exec();
     1418//      cout << query.executedQuery() << endl;
     1419        query.next();
     1420
     1421        AlbumID = query.value(0).toInt();       
     1422        }
     1423
     1424//Genres
     1425    int GenreID;
     1426    query.prepare("SELECT music_genres.genre_id FROM music_genres "
     1427                  " WHERE (((music_genres.genre)=:GENRE));");
     1428    query.bindValue(":GENRE", an_item->getGenre().utf8());
     1429    query.exec();
     1430//    cout << query.executedQuery() << endl;
     1431    if (query.size() > 0)
     1432        {
     1433        query.next();
     1434        GenreID = query.value(0).toInt();
     1435        }
     1436    else
     1437        {
     1438        query.prepare("INSERT INTO music_genres (genre) VALUES (:GENRE);");
     1439        query.bindValue(":GENRE", an_item->getGenre().utf8());
     1440        query.exec();
     1441//        cout << query.executedQuery() << endl;
     1442       
     1443        query.prepare("SELECT music_genres.genre_id FROM music_genres "
     1444                  " WHERE (((music_genres.genre)=:GENRE));");
     1445        query.bindValue(":GENRE", an_item->getGenre().utf8());
     1446        query.exec();
     1447//      cout << query.executedQuery() << endl;
     1448        query.next();
     1449        GenreID = query.value(0).toInt();       
     1450        }
     1451
     1452    query.prepare("UPDATE music_songs SET "
     1453                  "name = ? , "
     1454                  "artist_id = ? , "
     1455                  "album_id = ? , "
     1456                  "genre_id = ? , "
    13301457                  "year = ? , "
    1331                   "tracknum = ? , "
     1458                  "track = ? , "
    13321459                  "length = ? , "
    13331460                  "rating = ? , "
    13341461                  "lastplay = ? , "
    1335                   "playcount = ? , "
     1462                  "numplays = ? , "
    13361463                  "mythdigest = ? , "
    13371464                  "size = ? , "
    1338                   "date_added = ? , "
     1465                  "date_entered = ? , "
    13391466                  "date_modified = ? , "
    13401467                  "format = ? , "
    13411468                  "description = ? , "
    13421469                  "comment = ? , "
    13431470                  "compilation = ? , "
    1344                   "composer = ? , "
     1471                  "compilationartist_id = ? , "
    13451472                  "disc_count = ? , "
    13461473                  "disc_number = ? , "
    13471474                  "track_count = ? , "
     
    13491476                  "stop_time = ? , "
    13501477                  "eq_preset = ? , "
    13511478                  "relative_volume = ? , "
    1352                   "sample_rate = ? , "
     1479                  "bitrate = ? , "
    13531480                  "bpm = ?  "
    1354                   "WHERE intid = ? ;");
     1481                  "WHERE song_id = ? ;");
    13551482
    13561483    query.bindValue(0,  an_item->getTitle().utf8());
    1357     query.bindValue(1,  an_item->getArtist().utf8());
    1358     query.bindValue(2,  an_item->getAlbum().utf8());
    1359     query.bindValue(3,  an_item->getGenre().utf8());
     1484    query.bindValue(1,  ArtistID);
     1485    query.bindValue(2,  AlbumID);
     1486    query.bindValue(3,  GenreID);
    13601487    query.bindValue(4,  an_item->getYear());
    13611488    query.bindValue(5,  an_item->getTrack());
    13621489    query.bindValue(6,  an_item->getLength());
     
    13711498    query.bindValue(15, an_item->getDescription().utf8());
    13721499    query.bindValue(16, an_item->getComment().utf8());
    13731500    query.bindValue(17, an_item->getCompilation());
    1374     query.bindValue(18, an_item->getComposer().utf8());
     1501    query.bindValue(18, CoArtistID);
    13751502    query.bindValue(19, an_item->getDiscCount());
    13761503    query.bindValue(20, an_item->getDiscNumber());
    13771504    query.bindValue(21, an_item->getTrackCount());
     
    14671594
    14681595    MSqlQuery query(MSqlQuery::InitCon());
    14691596
    1470     query.prepare("SELECT name, songlist, playlistid FROM musicplaylist "
    1471                   "WHERE name != ? "
    1472                   "AND name != ? "
    1473                   "AND hostname = ? ;");
     1597    query.prepare("SELECT playlist_name, playlist_songs, playlist_id FROM music_saved_playlists "
     1598                  "WHERE playlist_name != ? "
     1599                  "AND playlist_name != ? ;");
    14741600       
    14751601    query.bindValue(0, "backup_playlist_storage");
    14761602    query.bindValue(1, "default_playlist_storage");
    1477     query.bindValue(2, hostname);
    14781603       
    14791604    query.exec();
    14801605
     
    16171742   
    16181743    MSqlQuery query(MSqlQuery::InitCon());
    16191744
    1620     query.prepare("UPDATE musicplaylist SET songlist = ?, name = ? WHERE "
    1621                   "playlistid = ? ;");
     1745    int songcount = 0, playtime = 0, an_int;
     1746    QStringList list = QStringList::split(",", db_song_list_string);
     1747    QStringList::iterator it = list.begin();
     1748    for (; it != list.end(); it++)
     1749    {
     1750        an_int = QString(*it).toInt();
     1751        if (an_int != 0)
     1752        {
     1753            songcount++;
     1754            query.prepare("SELECT length FROM music_songs WHERE song_id = :ID ;");
     1755            query.bindValue(":ID", an_int);
     1756            query.exec();
     1757            query.next();
     1758            playtime += query.value(0).toInt();
     1759        }
     1760    }
    16221761
     1762    query.prepare("UPDATE music_saved_playlists SET playlist_songs = ?, playlist_name = ? WHERE "
     1763                  "playlist_id = ?, songcount = ?, time = ? ;");
     1764
    16231765    query.bindValue(0, db_song_list_string);
    16241766    query.bindValue(1, a_playlist->getName().utf8());
    16251767    query.bindValue(2, a_playlist->getDbId());
     1768    query.bindValue(3, songcount);
     1769    query.bindValue(4, playtime);
    16261770       
    16271771    query.exec();
    16281772   
     
    16651809   
    16661810    MSqlQuery query(MSqlQuery::InitCon());
    16671811
    1668     query.prepare("INSERT INTO musicplaylist (name, hostname, songlist) values (?, ?, ?) ; ");
     1812    int songcount = 0, playtime = 0, an_int;
     1813    QStringList list = QStringList::split(",", db_song_list_string);
     1814    QStringList::iterator it = list.begin();
     1815    for (; it != list.end(); it++)
     1816    {
     1817        an_int = QString(*it).toInt();
     1818        if (an_int != 0)
     1819        {
     1820            songcount++;
     1821            query.prepare("SELECT length FROM music_songs WHERE song_id = :ID ;");
     1822            query.bindValue(":ID", an_int);
     1823            query.exec();
     1824            query.next();
     1825            playtime += query.value(0).toInt();
     1826        }
     1827    }
    16691828
     1829    query.prepare("INSERT INTO music_saved_playlists (playlist_name, hostname, playlist_songs, songcount, time) values (?, ?, ?, ?, ?) ; ");
     1830
    16701831    query.bindValue(0, a_playlist->getName().utf8());
    16711832    query.bindValue(1, hostname);
    16721833    query.bindValue(2, db_song_list_string);
     1834    query.bindValue(3, songcount);
     1835    query.bindValue(4, playtime);
    16731836       
    16741837    query.exec();
    16751838   
     
    16811844        return;
    16821845    }
    16831846   
    1684     query.prepare("SELECT playlistid FROM musicplaylist WHERE name = ? AND hostname = ? AND songlist = ? ; ");
     1847    if (a_playlist->getName() == "default_playlist_storage" || a_playlist->getName() == "backup_playlist_storage")
     1848        {
     1849        query.prepare("SELECT playlist_id FROM music_saved_playlists WHERE playlist_name = ? AND hostname = ? AND playlist_songs = ? ; ");
     1850        query.bindValue(0, a_playlist->getName().utf8());
     1851        query.bindValue(1, hostname);
     1852        query.bindValue(2, db_song_list_string);
     1853        }
     1854    else
     1855        {
     1856        query.prepare("SELECT playlist_id FROM music_saved_playlists WHERE playlist_name = ? AND playlist_songs = ? ; ");
     1857        query.bindValue(0, a_playlist->getName().utf8());
     1858        query.bindValue(1, db_song_list_string);
     1859        }
    16851860
    1686     query.bindValue(0, a_playlist->getName().utf8());
    1687     query.bindValue(1, hostname);
    1688     query.bindValue(2, db_song_list_string);
    16891861
    16901862    query.exec();
    16911863
     
    17761948
    17771949    MSqlQuery query(MSqlQuery::InitCon());
    17781950
    1779     query.prepare("DELETE FROM musicplaylist WHERE playlistid = ? ; ");
     1951    query.prepare("DELETE FROM music_saved_playlists WHERE playlist_id = ? ; ");
    17801952
    17811953    query.bindValue(0, playlist_database_id);
    17821954       
  • mfd/dbcheck.cpp

     
    99#include "mythtv/mythcontext.h"
    1010#include "mythtv/mythdbcon.h"
    1111
    12 const QString currentDatabaseVersion = "1005";
     12const QString currentDatabaseVersion = "1006";
    1313
    1414static void UpdateDBVersionNumber(const QString &newnumber)
    1515{
     
    323323
    324324        performActualUpdate(updates, "1005", dbver);
    325325    }
     326
     327
     328        if (dbver == "1005")
     329        {
     330            const QString updates[] = {
     331"CREATE TABLE music_albums ("
     332"    album_id int(11) unsigned NOT NULL auto_increment PRIMARY KEY,"
     333"    artist_id int(11) unsigned NOT NULL default '0',"
     334"    album_name varchar(255) NOT NULL default '',"
     335"    year smallint(6) NOT NULL default '0',"
     336"    compilation tinyint(1) unsigned NOT NULL default '0',"
     337"    INDEX idx_album_name(album_name)"
     338");",
     339"CREATE TABLE music_artists ("
     340"    artist_id int(11) unsigned NOT NULL auto_increment PRIMARY KEY,"
     341"    artist_name varchar(255) NOT NULL default '',"
     342"    INDEX idx_artist_name(artist_name)"
     343");",
     344"CREATE TABLE music_genres ("
     345"    genre_id int(11) unsigned NOT NULL auto_increment PRIMARY KEY,"
     346"    genre varchar(25) NOT NULL default '',"
     347"    INDEX idx_genre(genre)"
     348");",
     349"CREATE TABLE music_playlists ("
     350"    playlist_id int(11) unsigned NOT NULL auto_increment PRIMARY KEY,"
     351"    playlist_name varchar(255) NOT NULL default '',"
     352"    playlist_songs text NOT NULL default '',"
     353"    last_accessed timestamp NOT NULL,"
     354"    length int(11) unsigned NOT NULL default '0',"
     355"    songcount smallint(8) unsigned NOT NULL default '0',"
     356"    hostname VARCHAR(255) NOT NULL default ''"
     357");",
     358"CREATE TABLE music_songs ("
     359"    song_id int(11) unsigned NOT NULL auto_increment PRIMARY KEY,"
     360"    filename text NOT NULL default '',"
     361"    name varchar(255) NOT NULL default '',"
     362"    track smallint(6) unsigned NOT NULL default '0',"
     363"    artist_id int(11) unsigned NOT NULL default '0',"
     364"    album_id int(11) unsigned NOT NULL default '0',"
     365"    genre_id int(11) unsigned NOT NULL default '0',"
     366"    year smallint(6) NOT NULL default '0',"
     367"    length int(11) unsigned NOT NULL default '0',"
     368"    numplays int(11) unsigned NOT NULL default '0',"
     369"    rating tinyint(4) unsigned NOT NULL default '0',"
     370"    lastplay timestamp NOT NULL,"
     371"    date_entered datetime default NULL,"
     372"    date_modified datetime default NULL,"
     373"    format varchar(4) NOT NULL default '0',"
     374"    mythdigest VARCHAR(255),"
     375"    size BIGINT(20) unsigned,"
     376"    description VARCHAR(255),"
     377"    comment VARCHAR(255),"
     378"    disc_count SMALLINT(5) UNSIGNED DEFAULT '0',"
     379"    disc_number SMALLINT(5) UNSIGNED DEFAULT '0',"
     380"    track_count SMALLINT(5) UNSIGNED DEFAULT '0',"
     381"    start_time INT(10) UNSIGNED DEFAULT '0',"
     382"    stop_time INT(10) UNSIGNED,"
     383"    eq_preset VARCHAR(255),"
     384"    relative_volume TINYINT DEFAULT '0',"
     385"    bpm SMALLINT(5) UNSIGNED,"
     386"    INDEX idx_name(name),"
     387"    INDEX idx_mythdigest(mythdigest)"
     388");",
     389"CREATE TABLE music_stats ("
     390"    num_artists smallint(5) unsigned NOT NULL default '0',"
     391"    num_albums smallint(5) unsigned NOT NULL default '0',"
     392"    num_songs mediumint(8) unsigned NOT NULL default '0',"
     393"    num_genres tinyint(3) unsigned NOT NULL default '0',"
     394"    total_time varchar(12) NOT NULL default '0',"
     395"    total_size varchar(10) NOT NULL default '0'"
     396");",
     397"RENAME TABLE smartplaylist TO music_smartplaylists;",
     398"RENAME TABLE smartplaylistitem TO music_smartplaylist_items;",
     399"RENAME TABLE smartplaylistcategory TO music_smartplaylist_categories;",
     400// Run necessary SQL to migrate the table structure
     401"CREATE TEMPORARY TABLE tmp_artists"
     402"  SELECT DISTINCT artist FROM musicmetadata;",
     403"INSERT INTO tmp_artists"
     404"  SELECT DISTINCT compilation_artist"
     405"  FROM musicmetadata"
     406"  WHERE compilation_artist<>artist;",
     407"INSERT INTO music_artists (artist_name) SELECT DISTINCT artist FROM tmp_artists;",
     408"INSERT INTO music_albums (artist_id, album_name, year, compilation) "
     409"  SELECT artist_id, album, ROUND(AVG(year)) AS year, IF(SUM(compilation),1,0) AS compilation"
     410"  FROM musicmetadata"
     411"  LEFT JOIN music_artists ON compilation_artist=artist_name"
     412"  GROUP BY artist_id, album;",
     413"INSERT INTO music_genres (genre) SELECT DISTINCT genre FROM musicmetadata;",
     414"INSERT INTO music_songs "
     415"   (song_id, artist_id, album_id, genre_id, year, lastplay,"
     416"    date_entered, date_modified, name, track, length, size, numplays,"
     417"    rating, filename)"
     418"  SELECT intid, ma.artist_id, mb.album_id, mg.genre_id, mmd.year, lastplay,"
     419"         date_added, date_modified, title, tracknum, length, IFNULL(size,0), playcount,"
     420"         rating, filename"
     421"  FROM musicmetadata AS mmd"
     422"  LEFT JOIN music_artists AS ma ON mmd.artist=ma.artist_name"
     423"  LEFT JOIN music_artists AS mc ON mmd.compilation_artist=mc.artist_name"
     424"  LEFT JOIN music_albums AS mb ON mmd.album=mb.album_name AND mc.artist_id=mb.artist_id"
     425"  LEFT JOIN music_genres AS mg ON mmd.genre=mg.genre;",
     426"INSERT INTO music_playlists"
     427"  (playlist_id,playlist_name,playlist_songs,hostname)"
     428"  SELECT playlistid, name, songlist, hostname"
     429"  FROM musicplaylist;",
     430// Set all playlists to be global by killing the hostname
     431"UPDATE music_playlists"
     432"  SET hostname=''"
     433"  WHERE playlist_name='default_playlist_storage'"
     434"    OR playlist_name='backup_playlist_storage';",
     435//"DROP TABLE musicmetadata;",
     436//"DROP TABLE musicplaylist;",
     437//RENAME TABLE music_smartplaylists TO smartplaylist;RENAME TABLE music_smartplaylist_categories TO smartplaylistcategory;RENAME TABLE music_smartplaylist_items TO smartplaylistitem; DROP TABLE music_albums; DROP TABLE music_artists; DROP TABLE music_genres; DROP TABLE music_playlists; DROP TABLE music_songs; DROP TABLE music_stats;UPDATE settings SET data=1005 WHERE value='MusicDBSchemaVer';
     438""
     439};
     440        performActualUpdate(updates, "1006", dbver);
     441    }
    326442}
    327443