Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Initial commit

  • Loading branch information...
commit 90290ebe7b0dec1159306a00866eb90dd0764b7f 0 parents
@lalinsky authored
Showing with 12,868 additions and 0 deletions.
  1. +1 −0  .bzrignore
  2. +34 −0 README.txt
  3. +47 −0 mbslave-import.py
  4. +21 −0 mbslave-psql.py
  5. +129 −0 mbslave-sync.py
  6. +11 −0 mbslave.conf.default
  7. +209 −0 sql/CalculateRelatedTags.sql
  8. +16 −0 sql/CreateAll.sql
  9. +697 −0 sql/CreateFKConstraints.sql
  10. +659 −0 sql/CreateFunctions.sql
  11. +236 −0 sql/CreateIndexes.sql
  12. +45 −0 sql/CreateLinkFKs.pl
  13. +100 −0 sql/CreatePrimaryKeys.sql
  14. +325 −0 sql/CreateReplicationTriggers.sql
  15. +1,052 −0 sql/CreateTables.sql
  16. +101 −0 sql/CreateTriggers.sql
  17. +24 −0 sql/CreateViews.sql
  18. +13 −0 sql/DropAll.sql
  19. +143 −0 sql/DropFKConstraints.sql
  20. +34 −0 sql/DropFunctions.sql
  21. +174 −0 sql/DropIndexes.sql
  22. +100 −0 sql/DropPrimaryKeys.sql
  23. +90 −0 sql/DropReplicationTriggers.sql
  24. +169 −0 sql/DropTables.sql
  25. +41 −0 sql/DropTriggers.sql
  26. +9 −0 sql/DropViews.sql
  27. +44 −0 sql/ImportArtistRelations.sql
  28. +31 −0 sql/InsertDefaultRows.sql
  29. +83 −0 sql/PopulateCountries.pl
  30. +17 −0 sql/PopulateMetaTables.sql
  31. +25 −0 sql/ReplicationSetup.sql
  32. +144 −0 sql/contrib/musicip/track_frd/CreateTrackDateFunctions.sql
  33. +22 −0 sql/contrib/musicip/track_frd/CreateTrackDateTriggers.sql
  34. +19 −0 sql/contrib/musicip/track_frd/DropTrackDateFunctions.sql
  35. +14 −0 sql/contrib/musicip/track_frd/DropTrackDateTriggers.sql
  36. +1 −0  sql/contrib/musicip/track_frd/PopulateTrackDates.sql
  37. +68 −0 sql/contrib/musicip/track_frd/README
  38. +30 −0 sql/drop_all_links.pl
  39. +45 −0 sql/updates/20030201-1.sql
  40. +57 −0 sql/updates/20030201-2.sql
  41. +31 −0 sql/updates/20030321-1.sql
  42. +42 −0 sql/updates/20030401-1.sql
  43. +15 −0 sql/updates/20030809-1.sql
  44. +65 −0 sql/updates/20030910-1.sql
  45. +26 −0 sql/updates/20031004-0.sql
  46. +75 −0 sql/updates/20031004-1.pl
  47. +11 −0 sql/updates/20031004-2.sql
  48. +42 −0 sql/updates/20031004-3.sql
  49. +75 −0 sql/updates/20031019-1.sql
  50. +17 −0 sql/updates/20031025-1.sql
  51. +77 −0 sql/updates/20031025-2.pl
  52. +75 −0 sql/updates/20031025-3.pl
  53. +445 −0 sql/updates/20031126-1.sql
  54. +23 −0 sql/updates/20031216-1.sql
  55. +90 −0 sql/updates/20031231-1.sql
  56. +154 −0 sql/updates/20031231-2.pl
  57. +184 −0 sql/updates/20031231-3.sql
  58. +204 −0 sql/updates/20040220-1.sql
  59. +276 −0 sql/updates/20040326-1.pl
  60. +41 −0 sql/updates/20040409-1.sql
  61. +42 −0 sql/updates/20040428-1.sql
  62. +143 −0 sql/updates/20040516-1.pl
  63. +12 −0 sql/updates/20040516-2.sql
  64. +75 −0 sql/updates/20040522-1.sql
  65. +25 −0 sql/updates/20040608-1.sql
  66. +97 −0 sql/updates/20040730-1.pl
  67. +229 −0 sql/updates/20040730-2.sql
  68. +145 −0 sql/updates/20040916-1.sql
  69. +543 −0 sql/updates/20050114-1.sql
  70. +102 −0 sql/updates/20050114-2.sql
  71. +858 −0 sql/updates/20050420-1.sql
  72. +21 −0 sql/updates/20050420-2.sql
  73. +17 −0 sql/updates/20050424-1.sql
  74. +146 −0 sql/updates/20050527-1.pl
  75. +25 −0 sql/updates/20050928.sql
  76. +96 −0 sql/updates/20060305-1.pl
  77. +96 −0 sql/updates/20060305-2.pl
  78. +60 −0 sql/updates/20060310-1.sh
  79. +88 −0 sql/updates/20060310-1.sql
  80. +23 −0 sql/updates/20060531-1.sql
  81. +255 −0 sql/updates/20061104-1.sql
  82. +136 −0 sql/updates/20061104-2.sql
  83. +66 −0 sql/updates/20061104-3.sql
  84. +27 −0 sql/updates/20061104-4.sql
  85. +80 −0 sql/updates/20070401-1.sql
  86. +94 −0 sql/updates/20070622-1.sql
  87. +72 −0 sql/updates/20070622-2.sql
  88. +61 −0 sql/updates/20070622-3.sql
  89. +20 −0 sql/updates/20070719-1.sql
  90. +19 −0 sql/updates/20070719-2.sql
  91. +153 −0 sql/updates/20070813-1.sql
  92. +27 −0 sql/updates/20070921-1.sql
  93. +60 −0 sql/updates/20071212-1.sql
  94. +36 −0 sql/updates/20080201-1.sql
  95. +37 −0 sql/updates/20080529.sql
  96. +49 −0 sql/updates/20080610-1.sql
  97. +41 −0 sql/updates/20080610-2.sql
  98. +21 −0 sql/updates/20080707-1.sql
  99. +58 −0 sql/updates/20080707-2.sql
  100. +76 −0 sql/updates/20080711-1.sql
  101. +28 −0 sql/updates/20080729.sql
  102. +13 −0 sql/updates/20081017-1.sql
  103. +15 −0 sql/updates/20081017-2.sql
  104. +40 −0 sql/updates/20081027.sql
  105. +303 −0 sql/updates/20081115-1.sql
  106. +83 −0 sql/updates/20081123.sql
  107. +19 −0 sql/updates/20090220.sql
  108. +319 −0 sql/updates/20090402-1.pl
  109. +119 −0 sql/updates/20090402-2.sql
  110. +102 −0 sql/updates/20090402-3.sql
  111. +19 −0 sql/updates/20090402-4.sql
  112. +22 −0 sql/updates/20090416-1.sql
  113. +13 −0 sql/updates/20090416-2.sql
  114. +48 −0 sql/updates/20090524-1.pl
  115. +45 −0 sql/updates/PopulateAlbumDateAdded.pl
  116. +36 −0 sql/updates/puid_load.sql
  117. +21 −0 sql/vertical/rawdata/CreateFKConstraints.sql
  118. +61 −0 sql/vertical/rawdata/CreateIndexes.sql
  119. +27 −0 sql/vertical/rawdata/CreatePrimaryKeys.sql
  120. +144 −0 sql/vertical/rawdata/CreateTables.sql
  121. +8 −0 sql/vertical/rawdata/DropFKConstraints.sql
  122. +53 −0 sql/vertical/rawdata/DropIndexes.sql
  123. +27 −0 sql/vertical/rawdata/DropPrimaryKeys.sql
  124. +24 −0 sql/vertical/rawdata/DropTables.sql
1  .bzrignore
@@ -0,0 +1 @@
+mbslave.conf
34 README.txt
@@ -0,0 +1,34 @@
+Installation
+============
+
+1. Setup a database and create mbslave.conf by copying and editing
+ mbslave.conf.default
+
+2. Prepare empty schema for the MusicBrainz database and create the
+ table structure:
+
+ $ echo 'CREATE SCHEMA musicbrainz;' | ./mbslave-psql
+ $ ./mbslave-psql.py <sql/CreateTables.sql
+
+3. Download the MusicBrainz database dump files from
+ http://musicbrainz.org/doc/Database_Download
+
+4. Import the data dumps, for example:
+
+ $ ./mbslave-import.py mbdump.tar.bz2 mbdump-derived.tar.bz2
+
+5. Setup primary keys, indexes, views and functions:
+
+ $ ./mbslave-psql.py <sql/CreatePrimaryKeys.sql
+ $ ./mbslave-psql.py <sql/CreateIndexes.sql
+ $ ./mbslave-psql.py <sql/CreateViews.sql
+ $ ./mbslave-psql.py <sql/CreateFunctions.sql
+
+6. Vacuum the newly created database (optional)
+
+ $ echo 'VACUUM ANALYZE;' | ./mbslave-psql.py
+
+7. Run the initial replication:
+
+ $ ./mbslave-sync.py
+
47 mbslave-import.py
@@ -0,0 +1,47 @@
+#!/usr/bin/env python
+
+import ConfigParser
+import psycopg2
+import tarfile
+import sys
+import os
+
+
+def load_tar(filename, db, schema, ignored_tables):
+ print "Importing data from", filename
+ tar = tarfile.open(filename, 'r:bz2')
+ cursor = db.cursor()
+ for member in tar:
+ if not member.name.startswith('mbdump/'):
+ continue
+ table = member.name.split('/')[1].replace('_sanitised', '')
+ fulltable = schema + "." + table
+ if table in ignored_tables:
+ print " - Ignoring", fulltable
+ continue
+ cursor.execute("SELECT 1 FROM %s LIMIT 1" % fulltable)
+ if cursor.fetchone():
+ print " - Skipping", fulltable, "(already contains data)"
+ continue
+ print " - Loading", fulltable
+ cursor.copy_from(tar.extractfile(member), fulltable)
+ db.commit()
+
+
+config = ConfigParser.RawConfigParser()
+config.read(os.path.dirname(__file__) + '/mbslave.conf')
+
+opts = {}
+opts['database'] = config.get('DATABASE', 'name')
+opts['user'] = config.get('DATABASE', 'user')
+if config.has_option('DATABASE', 'host'):
+ opts['host'] = config.get('DATABASE', 'host')
+if config.has_option('DATABASE', 'port'):
+ opts['port'] = config.get('DATABASE', 'port')
+db = psycopg2.connect(**opts)
+
+schema = config.get('DATABASE', 'schema')
+ignored_tables = set(config.get('TABLES', 'ignore').split(','))
+for filename in sys.argv[1:]:
+ load_tar(filename, db, schema, ignored_tables)
+
21 mbslave-psql.py
@@ -0,0 +1,21 @@
+#!/usr/bin/env python
+
+import ConfigParser
+import os
+
+config = ConfigParser.RawConfigParser()
+config.read(os.path.dirname(__file__) + '/mbslave.conf')
+
+args = []
+args.append('-U')
+args.append(config.get('DATABASE', 'user'))
+if config.has_option('DATABASE', 'host'):
+ args.append('-h')
+ args.append(config.get('DATABASE', 'host'))
+if config.has_option('DATABASE', 'port'):
+ args.append('-p')
+ args.append(config.get('DATABASE', 'port'))
+args.append(config.get('DATABASE', 'name'))
+
+os.environ['PGOPTIONS'] = '-c search_path=%s' % config.get('DATABASE', 'schema')
+os.execvp("psql", args)
129 mbslave-sync.py
@@ -0,0 +1,129 @@
+#!/usr/bin/env python
+
+import ConfigParser
+import psycopg2
+import tarfile
+import sys
+import os
+import re
+
+
+def parse_data_fields(s):
+ fields = {}
+ for name, value in re.findall(r'''"([^"]+)"=('(?:''|[^'])*') ''', s):
+ if not value:
+ value = None
+ else:
+ value = value[1:-1].replace("''", "'").replace("\\\\", "\\")
+ fields[name] = value
+ return fields
+
+
+def parse_bool(s):
+ return s == 't'
+
+
+ESCAPES = (('\\b', '\b'), ('\\f', '\f'), ('\\n', '\n'), ('\\r', '\r'),
+ ('\\t', '\t'), ('\\v', '\v'), ('\\\\', '\\'))
+
+def unescape(s):
+ if s == '\\N':
+ return None
+ for orig, repl in ESCAPES:
+ s = s.replace(orig, repl)
+ return s
+
+
+def read_psql_dump(fp, types):
+ for line in fp:
+ values = map(unescape, line.rstrip('\r\n').split('\t'))
+ for i, value in enumerate(values):
+ if value is not None:
+ values[i] = types[i](value)
+ yield values
+
+
+class PacketImporter(object):
+
+ def __init__(self, db, schema, ignored_tables):
+ self._db = db
+ self._data = {}
+ self._transactions = {}
+ self._schema = schema
+ self._ignored_tables = ignored_tables
+
+ def load_pending_data(self, fp):
+ dump = read_psql_dump(fp, [int, parse_bool, parse_data_fields])
+ for id, key, values in dump:
+ self._data[(id, key)] = values
+
+ def load_pending(self, fp):
+ dump = read_psql_dump(fp, [int, str, str, int])
+ for id, table, type, xid in dump:
+ table = table.split(".")[1].strip('"')
+ transaction = self._transactions.setdefault(xid, [])
+ transaction.append((id, table, type))
+
+ def process(self):
+ cursor = self._db.cursor()
+ for xid in sorted(self._transactions.keys()):
+ transaction = self._transactions[xid]
+ #print ' - Running transaction', xid
+ #print 'BEGIN; --', xid
+ for id, table, type in sorted(transaction):
+ if table in self._ignored_tables:
+ continue
+ fulltable = self._schema + '.' + table
+ if type == 'd':
+ sql = 'DELETE FROM %s' % (fulltable,)
+ params = []
+ elif type == 'u':
+ values = self._data[(id, False)]
+ sql_values = ', '.join('%s=%%s' % i for i in values)
+ sql = 'UPDATE %s SET %s' % (fulltable, sql_values)
+ params = values.values()
+ elif type == 'i':
+ values = self._data[(id, False)]
+ sql_columns = ', '.join(values.keys())
+ sql_values = ', '.join(['%s'] * len(values))
+ sql = 'INSERT INTO %s (%s) VALUES (%s)' % (fulltable, sql_columns, sql_values)
+ params = values.values()
+ if type == 'd' or type == 'u':
+ values = self._data[(id, True)]
+ sql += ' WHERE ' + ' AND '.join('%s=%%s' % i for i in values.keys())
+ params.extend(values.values())
+ cursor.execute(sql, params)
+ #print sql, params
+ #print 'COMMIT; --', xid
+ self._db.commit()
+
+
+def process_tar(filename, db, schema, ignored_tables):
+ print "Processing", filename
+ tar = tarfile.open(filename, 'r:bz2')
+ importer = PacketImporter(db, schema, ignored_tables)
+ for member in tar:
+ if member.name == 'mbdump/Pending':
+ importer.load_pending(tar.extractfile(member))
+ elif member.name == 'mbdump/PendingData':
+ importer.load_pending_data(tar.extractfile(member))
+ importer.process()
+
+
+config = ConfigParser.RawConfigParser()
+config.read(os.path.dirname(__file__) + '/mbslave.conf')
+
+opts = {}
+opts['database'] = config.get('DATABASE', 'name')
+opts['user'] = config.get('DATABASE', 'user')
+if config.has_option('DATABASE', 'host'):
+ opts['host'] = config.get('DATABASE', 'host')
+if config.has_option('DATABASE', 'port'):
+ opts['port'] = config.get('DATABASE', 'port')
+db = psycopg2.connect(**opts)
+
+schema = config.get('DATABASE', 'schema')
+ignored_tables = set(config.get('TABLES', 'ignore').split(','))
+for filename in sys.argv[1:]:
+ process_tar(filename, db, schema, ignored_tables)
+
11 mbslave.conf.default
@@ -0,0 +1,11 @@
+[DATABASE]
+host=localhost
+port=5432
+name=musicbrainz_db
+user=musicbrainz_user
+schema=public
+
+[TABLES]
+ignore=
+#ignore=albumwords,trackwords,artistwords,labelwords,wordlist,puid,puidjoin,trm,trmjoin
+
209 sql/CalculateRelatedTags.sql
@@ -0,0 +1,209 @@
+\set ON_ERROR_STOP 1
+
+BEGIN;
+
+----------------------------------------
+-- Calculate maximum tag count for each entity, this is used
+-- later to weight relations between common tags.
+----------------------------------------
+
+CREATE TEMPORARY TABLE tmp_artist_tag_count
+(
+ id INTEGER NOT NULL,
+ max_count INTEGER NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_release_tag_count
+(
+ id INTEGER NOT NULL,
+ max_count INTEGER NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_label_tag_count
+(
+ id INTEGER NOT NULL,
+ max_count INTEGER NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_track_tag_count
+(
+ id INTEGER NOT NULL,
+ max_count INTEGER NOT NULL
+);
+
+
+INSERT INTO tmp_artist_tag_count SELECT
+ a.id, MAX(t.count) AS max_count
+FROM
+ artist a
+ JOIN artist_tag t ON t.artist = a.id
+GROUP BY a.id;
+
+
+INSERT INTO tmp_release_tag_count SELECT
+ a.id, MAX(t.count) AS max_count
+FROM
+ album a
+ JOIN release_tag t ON t.release = a.id
+GROUP BY a.id;
+
+
+INSERT INTO tmp_label_tag_count SELECT
+ a.id, MAX(t.count) AS max_count
+FROM
+ label a
+ JOIN label_tag t ON t.label = a.id
+GROUP BY a.id;
+
+
+INSERT INTO tmp_track_tag_count SELECT
+ a.id, MAX(t.count) AS max_count
+FROM
+ track a
+ JOIN track_tag t ON t.track = a.id
+GROUP BY a.id;
+
+
+CREATE UNIQUE INDEX tmp_artist_tag_count_id_idx ON tmp_artist_tag_count (id);
+CREATE UNIQUE INDEX tmp_release_tag_count_id_idx ON tmp_release_tag_count (id);
+CREATE UNIQUE INDEX tmp_label_tag_count_id_idx ON tmp_label_tag_count (id);
+CREATE UNIQUE INDEX tmp_track_tag_count_id_idx ON tmp_track_tag_count (id);
+
+
+----------------------------------------
+-- Calculate weighted relations between tags from common tags on entities.
+----------------------------------------
+
+
+CREATE TEMPORARY TABLE tmp_artist_tag_relation
+(
+ tag1 INTEGER NOT NULL,
+ tag2 INTEGER NOT NULL,
+ weight FLOAT NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_release_tag_relation
+(
+ tag1 INTEGER NOT NULL,
+ tag2 INTEGER NOT NULL,
+ weight FLOAT NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_label_tag_relation
+(
+ tag1 INTEGER NOT NULL,
+ tag2 INTEGER NOT NULL,
+ weight FLOAT NOT NULL
+);
+
+CREATE TEMPORARY TABLE tmp_track_tag_relation
+(
+ tag1 INTEGER NOT NULL,
+ tag2 INTEGER NOT NULL,
+ weight FLOAT NOT NULL
+);
+
+
+INSERT INTO tmp_artist_tag_relation SELECT
+ t1.tag, t2.tag,
+ SUM(((t1.count + t2.count) / 2.0) / tc.max_count) AS weight
+FROM
+ artist a
+ JOIN artist_tag t1 ON t1.artist = a.id
+ JOIN artist_tag t2 ON t2.artist = a.id
+ LEFT JOIN tmp_artist_tag_count tc ON a.id = tc.id
+WHERE t1.tag < t2.tag
+GROUP BY t1.tag, t2.tag
+HAVING COUNT(*) >= 3;
+
+
+INSERT INTO tmp_release_tag_relation SELECT
+ t1.tag, t2.tag,
+ SUM(((t1.count + t2.count) / 2.0) / tc.max_count) AS weight
+FROM
+ album a
+ JOIN release_tag t1 ON t1.release = a.id
+ JOIN release_tag t2 ON t2.release = a.id
+ LEFT JOIN tmp_release_tag_count tc ON a.id = tc.id
+WHERE t1.tag < t2.tag
+GROUP BY t1.tag, t2.tag
+HAVING COUNT(*) >= 3;
+
+
+INSERT INTO tmp_label_tag_relation SELECT
+ t1.tag, t2.tag,
+ SUM(((t1.count + t2.count) / 2.0) / tc.max_count) AS weight
+FROM
+ label a
+ JOIN label_tag t1 ON t1.label = a.id
+ JOIN label_tag t2 ON t2.label = a.id
+ LEFT JOIN tmp_label_tag_count tc ON a.id = tc.id
+WHERE t1.tag < t2.tag
+GROUP BY t1.tag, t2.tag
+HAVING COUNT(*) >= 3;
+
+
+INSERT INTO tmp_track_tag_relation SELECT
+ t1.tag, t2.tag,
+ SUM(((t1.count + t2.count) / 2.0) / tc.max_count) AS weight
+FROM
+ track a
+ JOIN track_tag t1 ON t1.track = a.id
+ JOIN track_tag t2 ON t2.track = a.id
+ LEFT JOIN tmp_track_tag_count tc ON a.id = tc.id
+WHERE t1.tag < t2.tag
+GROUP BY t1.tag, t2.tag
+HAVING COUNT(*) >= 3;
+
+
+CREATE INDEX tmp_artist_tag_relation_tag1 ON tmp_artist_tag_relation (tag1);
+CREATE INDEX tmp_artist_tag_relation_tag2 ON tmp_artist_tag_relation (tag2);
+
+CREATE INDEX tmp_release_tag_relation_tag1 ON tmp_release_tag_relation (tag1);
+CREATE INDEX tmp_release_tag_relation_tag2 ON tmp_release_tag_relation (tag2);
+
+CREATE INDEX tmp_label_tag_relation_tag1 ON tmp_label_tag_relation (tag1);
+CREATE INDEX tmp_label_tag_relation_tag2 ON tmp_label_tag_relation (tag2);
+
+CREATE INDEX tmp_track_tag_relation_tag1 ON tmp_track_tag_relation (tag1);
+CREATE INDEX tmp_track_tag_relation_tag2 ON tmp_track_tag_relation (tag2);
+
+
+----------------------------------------
+-- Join the temporary table and calculate the final weights.
+----------------------------------------
+
+TRUNCATE tag_relation;
+
+INSERT INTO tag_relation SELECT
+ COALESCE(r1.tag1, r2.tag1, r3.tag1, r4.tag1) AS tag1,
+ COALESCE(r1.tag2, r2.tag2, r3.tag2, r4.tag2) AS tag2,
+ COALESCE(r1.weight, 0) + COALESCE(r2.weight, 0) + COALESCE(r3.weight, 0) + COALESCE(r4.weight, 0) AS weight
+FROM
+ tmp_artist_tag_relation r1
+ FULL OUTER JOIN tmp_release_tag_relation r2
+ ON (r2.tag1 = r1.tag1 AND r2.tag2 = r1.tag2)
+ FULL OUTER JOIN tmp_label_tag_relation r3
+ ON (r3.tag1 = COALESCE(r1.tag1, r2.tag1) AND r3.tag2 = COALESCE(r1.tag2, r2.tag2))
+ FULL OUTER JOIN tmp_track_tag_relation r4
+ ON (r4.tag1 = COALESCE(r1.tag1, r2.tag1, r3.tag1) AND r4.tag2 = COALESCE(r1.tag2, r2.tag2, r3.tag2));
+
+/*
+
+Usage:
+
+SELECT
+ t1.name, t2.name, tr.weight
+FROM
+ tag t1
+ JOIN tag_relation tr ON t1.id = tr.tag1 OR t1.id = tr.tag2
+ JOIN tag t2 ON t1.id != t2.id AND (t2.id = tr.tag1 OR t2.id = tr.tag2)
+WHERE
+ t1.name = 'jazz'
+ORDER BY tr.weight DESC;
+
+*/
+
+COMMIT;
+
+VACUUM ANALYZE tag_relation;
16 sql/CreateAll.sql
@@ -0,0 +1,16 @@
+\set ON_ERROR_STOP 1
+
+-- This script is the really quick and dirty way to set up a database
+-- (although it will contain no data - you might want to run
+-- admin/sql/InsertDefaultRows.sql too). It's really just a debug /
+-- development tool. If you want to import a dataset, use "InitDb.pl"
+-- instead.
+
+\i admin/sql/CreateTables.sql
+\i admin/sql/CreatePrimaryKeys.sql
+\i admin/sql/CreateIndexes.sql
+\i admin/sql/CreateFKConstraints.sql
+\i admin/sql/CreateViews.sql
+\i admin/sql/CreateFunctions.sql
+\i admin/sql/CreateTriggers.sql
+\i admin/sql/CreateReplicationTriggers.sql
697 sql/CreateFKConstraints.sql
@@ -0,0 +1,697 @@
+--\set ON_ERROR_STOP 1
+
+-- Alphabetical order by table, then constraint
+
+-- No BEGIN/COMMIT here. Each FK is created in its own transaction;
+-- this is mainly because if you're setting up a big database, it
+-- could get really annoying if it takes a long time to create the FKs,
+-- only for the last one to fail and the whole lot gets rolled back.
+-- It should also be more efficient, of course.
+
+ALTER TABLE album
+ ADD CONSTRAINT album_fk_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE album
+ ADD CONSTRAINT album_fk_release_group
+ FOREIGN KEY (release_group)
+ REFERENCES release_group(id);
+
+ALTER TABLE album_amazon_asin
+ ADD CONSTRAINT album_amazon_asin_fk_album
+ FOREIGN KEY (album)
+ REFERENCES album(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE album_cdtoc
+ ADD CONSTRAINT album_cdtoc_fk_album
+ FOREIGN KEY (album)
+ REFERENCES album(id);
+
+ALTER TABLE album_cdtoc
+ ADD CONSTRAINT album_cdtoc_fk_cdtoc
+ FOREIGN KEY (cdtoc)
+ REFERENCES cdtoc(id);
+
+ALTER TABLE albumjoin
+ ADD CONSTRAINT albumjoin_fk_album
+ FOREIGN KEY (album)
+ REFERENCES album(id);
+
+ALTER TABLE albumjoin
+ ADD CONSTRAINT albumjoin_fk_track
+ FOREIGN KEY (track)
+ REFERENCES track(id);
+
+ALTER TABLE albummeta
+ ADD CONSTRAINT albummeta_fk_album
+ FOREIGN KEY (id)
+ REFERENCES album(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE albumwords
+ ADD CONSTRAINT albumwords_fk_albumid
+ FOREIGN KEY (albumid)
+ REFERENCES album (id)
+ ON DELETE CASCADE;
+
+ALTER TABLE artistalias
+ ADD CONSTRAINT artistalias_fk_ref
+ FOREIGN KEY (ref)
+ REFERENCES artist(id);
+
+ALTER TABLE artist_meta
+ ADD CONSTRAINT fk_artist_meta_artist
+ FOREIGN KEY (id)
+ REFERENCES artist(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE artist_relation
+ ADD CONSTRAINT artist_relation_fk_artist1
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE artist_relation
+ ADD CONSTRAINT artist_relation_fk_artist2
+ FOREIGN KEY (ref)
+ REFERENCES artist(id);
+
+ALTER TABLE artist_tag
+ ADD CONSTRAINT fk_artist_tag_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE artist_tag
+ ADD CONSTRAINT fk_artist_tag_tag
+ FOREIGN KEY (tag)
+ REFERENCES tag(id);
+
+ALTER TABLE artistwords
+ ADD CONSTRAINT artistwords_fk_artistid
+ FOREIGN KEY (artistid)
+ REFERENCES artist (id)
+ ON DELETE CASCADE;
+
+ALTER TABLE automod_election
+ ADD CONSTRAINT automod_election_fk_candidate
+ FOREIGN KEY (candidate)
+ REFERENCES moderator(id);
+
+ALTER TABLE automod_election
+ ADD CONSTRAINT automod_election_fk_proposer
+ FOREIGN KEY (proposer)
+ REFERENCES moderator(id);
+
+ALTER TABLE automod_election
+ ADD CONSTRAINT automod_election_fk_seconder_1
+ FOREIGN KEY (seconder_1)
+ REFERENCES moderator(id);
+
+ALTER TABLE automod_election
+ ADD CONSTRAINT automod_election_fk_seconder_2
+ FOREIGN KEY (seconder_2)
+ REFERENCES moderator(id);
+
+ALTER TABLE automod_election_vote
+ ADD CONSTRAINT automod_election_vote_fk_automod_election
+ FOREIGN KEY (automod_election)
+ REFERENCES automod_election(id);
+
+ALTER TABLE automod_election_vote
+ ADD CONSTRAINT automod_election_vote_fk_voter
+ FOREIGN KEY (voter)
+ REFERENCES moderator(id);
+
+ALTER TABLE isrc
+ ADD CONSTRAINT fk_isrc_track
+ FOREIGN KEY (track)
+ REFERENCES track(id);
+
+ALTER TABLE label
+ ADD CONSTRAINT label_fk_country
+ FOREIGN KEY (country)
+ REFERENCES country(id);
+
+ALTER TABLE label_meta
+ ADD CONSTRAINT fk_label_meta_label
+ FOREIGN KEY (id)
+ REFERENCES label(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE labelalias
+ ADD CONSTRAINT labelalias_fk_ref
+ FOREIGN KEY (ref)
+ REFERENCES label(id);
+
+ALTER TABLE label_tag
+ ADD CONSTRAINT fk_label_tag_track
+ FOREIGN KEY (label)
+ REFERENCES label(id);
+
+ALTER TABLE label_tag
+ ADD CONSTRAINT fk_label_tag_tag
+ FOREIGN KEY (tag)
+ REFERENCES tag(id);
+
+ALTER TABLE labelwords
+ ADD CONSTRAINT labelwords_fk_labelid
+ FOREIGN KEY (labelid)
+ REFERENCES label (id)
+ ON DELETE CASCADE;
+
+ALTER TABLE l_album_album
+ ADD CONSTRAINT fk_l_album_album_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_album_album(id);
+
+ALTER TABLE l_album_album
+ ADD CONSTRAINT fk_l_album_album_link0
+ FOREIGN KEY (link0)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_album
+ ADD CONSTRAINT fk_l_album_album_link1
+ FOREIGN KEY (link1)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_artist
+ ADD CONSTRAINT fk_l_album_artist_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_album_artist(id);
+
+ALTER TABLE l_album_artist
+ ADD CONSTRAINT fk_l_album_artist_link0
+ FOREIGN KEY (link0)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_artist
+ ADD CONSTRAINT fk_l_album_artist_link1
+ FOREIGN KEY (link1)
+ REFERENCES artist(id);
+
+ALTER TABLE l_album_label
+ ADD CONSTRAINT fk_l_album_label_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_album_label(id);
+
+ALTER TABLE l_album_label
+ ADD CONSTRAINT fk_l_album_label_link0
+ FOREIGN KEY (link0)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_label
+ ADD CONSTRAINT fk_l_album_label_link1
+ FOREIGN KEY (link1)
+ REFERENCES label(id);
+
+ALTER TABLE l_album_track
+ ADD CONSTRAINT fk_l_album_track_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_album_track(id);
+
+ALTER TABLE l_album_track
+ ADD CONSTRAINT fk_l_album_track_link0
+ FOREIGN KEY (link0)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_track
+ ADD CONSTRAINT fk_l_album_track_link1
+ FOREIGN KEY (link1)
+ REFERENCES track(id);
+
+ALTER TABLE l_album_url
+ ADD CONSTRAINT fk_l_album_url_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_album_url(id);
+
+ALTER TABLE l_album_url
+ ADD CONSTRAINT fk_l_album_url_link0
+ FOREIGN KEY (link0)
+ REFERENCES album(id);
+
+ALTER TABLE l_album_url
+ ADD CONSTRAINT fk_l_album_url_link1
+ FOREIGN KEY (link1)
+ REFERENCES url(id);
+
+ALTER TABLE l_artist_artist
+ ADD CONSTRAINT fk_l_artist_artist_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_artist_artist(id);
+
+ALTER TABLE l_artist_artist
+ ADD CONSTRAINT fk_l_artist_artist_link0
+ FOREIGN KEY (link0)
+ REFERENCES artist(id);
+
+ALTER TABLE l_artist_artist
+ ADD CONSTRAINT fk_l_artist_artist_link1
+ FOREIGN KEY (link1)
+ REFERENCES artist(id);
+
+ALTER TABLE l_artist_label
+ ADD CONSTRAINT fk_l_artist_label_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_artist_label(id);
+
+ALTER TABLE l_artist_label
+ ADD CONSTRAINT fk_l_artist_label_link0
+ FOREIGN KEY (link0)
+ REFERENCES artist(id);
+
+ALTER TABLE l_artist_label
+ ADD CONSTRAINT fk_l_artist_label_link1
+ FOREIGN KEY (link1)
+ REFERENCES label(id);
+
+ALTER TABLE l_artist_track
+ ADD CONSTRAINT fk_l_artist_track_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_artist_track(id);
+
+ALTER TABLE l_artist_track
+ ADD CONSTRAINT fk_l_artist_track_link0
+ FOREIGN KEY (link0)
+ REFERENCES artist(id);
+
+ALTER TABLE l_artist_track
+ ADD CONSTRAINT fk_l_artist_track_link1
+ FOREIGN KEY (link1)
+ REFERENCES track(id);
+
+ALTER TABLE l_artist_url
+ ADD CONSTRAINT fk_l_artist_url_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_artist_url(id);
+
+ALTER TABLE l_artist_url
+ ADD CONSTRAINT fk_l_artist_url_link0
+ FOREIGN KEY (link0)
+ REFERENCES artist(id);
+
+ALTER TABLE l_artist_url
+ ADD CONSTRAINT fk_l_artist_url_link1
+ FOREIGN KEY (link1)
+ REFERENCES url(id);
+
+ALTER TABLE l_label_label
+ ADD CONSTRAINT fk_l_label_label_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_label_label(id);
+
+ALTER TABLE l_label_label
+ ADD CONSTRAINT fk_l_label_label_link0
+ FOREIGN KEY (link0)
+ REFERENCES label(id);
+
+ALTER TABLE l_label_label
+ ADD CONSTRAINT fk_l_label_label_link1
+ FOREIGN KEY (link1)
+ REFERENCES label(id);
+
+ALTER TABLE l_label_track
+ ADD CONSTRAINT fk_l_label_track_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_label_track(id);
+
+ALTER TABLE l_label_track
+ ADD CONSTRAINT fk_l_label_track_link0
+ FOREIGN KEY (link0)
+ REFERENCES label(id);
+
+ALTER TABLE l_label_track
+ ADD CONSTRAINT fk_l_label_track_link1
+ FOREIGN KEY (link1)
+ REFERENCES track(id);
+
+ALTER TABLE l_label_url
+ ADD CONSTRAINT fk_l_label_url_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_label_url(id);
+
+ALTER TABLE l_label_url
+ ADD CONSTRAINT fk_l_label_url_link0
+ FOREIGN KEY (link0)
+ REFERENCES label(id);
+
+ALTER TABLE l_label_url
+ ADD CONSTRAINT fk_l_label_url_link1
+ FOREIGN KEY (link1)
+ REFERENCES url(id);
+
+ALTER TABLE l_track_track
+ ADD CONSTRAINT fk_l_track_track_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_track_track(id);
+
+ALTER TABLE l_track_track
+ ADD CONSTRAINT fk_l_track_track_link0
+ FOREIGN KEY (link0)
+ REFERENCES track(id);
+
+ALTER TABLE l_track_track
+ ADD CONSTRAINT fk_l_track_track_link1
+ FOREIGN KEY (link1)
+ REFERENCES track(id);
+
+ALTER TABLE l_track_url
+ ADD CONSTRAINT fk_l_track_url_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_track_url(id);
+
+ALTER TABLE l_track_url
+ ADD CONSTRAINT fk_l_track_url_link0
+ FOREIGN KEY (link0)
+ REFERENCES track(id);
+
+ALTER TABLE l_track_url
+ ADD CONSTRAINT fk_l_track_url_link1
+ FOREIGN KEY (link1)
+ REFERENCES url(id);
+
+ALTER TABLE l_url_url
+ ADD CONSTRAINT fk_l_url_url_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES lt_url_url(id);
+
+ALTER TABLE l_url_url
+ ADD CONSTRAINT fk_l_url_url_link0
+ FOREIGN KEY (link0)
+ REFERENCES url(id);
+
+ALTER TABLE l_url_url
+ ADD CONSTRAINT fk_l_url_url_link1
+ FOREIGN KEY (link1)
+ REFERENCES url(id);
+
+ALTER TABLE link_attribute
+ ADD CONSTRAINT fk_link_attribute_type
+ FOREIGN KEY (attribute_type)
+ REFERENCES link_attribute_type(id);
+
+ALTER TABLE lt_album_album
+ ADD CONSTRAINT fk_lt_album_album_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_album_album(id);
+
+ALTER TABLE lt_album_artist
+ ADD CONSTRAINT fk_lt_album_artist_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_album_artist(id);
+
+ALTER TABLE lt_album_label
+ ADD CONSTRAINT fk_lt_album_label_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_album_label(id);
+
+ALTER TABLE lt_album_track
+ ADD CONSTRAINT fk_lt_album_track_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_album_track(id);
+
+ALTER TABLE lt_album_url
+ ADD CONSTRAINT fk_lt_album_url_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_album_url(id);
+
+ALTER TABLE lt_artist_artist
+ ADD CONSTRAINT fk_lt_artist_artist_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_artist_artist(id);
+
+ALTER TABLE lt_artist_label
+ ADD CONSTRAINT fk_lt_artist_label_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_artist_label(id);
+
+ALTER TABLE lt_artist_track
+ ADD CONSTRAINT fk_lt_artist_track_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_artist_track(id);
+
+ALTER TABLE lt_artist_url
+ ADD CONSTRAINT fk_lt_artist_url_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_artist_url(id);
+
+ALTER TABLE lt_label_label
+ ADD CONSTRAINT fk_lt_label_label_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_label_label(id);
+
+ALTER TABLE lt_label_track
+ ADD CONSTRAINT fk_lt_label_track_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_label_track(id);
+
+ALTER TABLE lt_label_url
+ ADD CONSTRAINT fk_lt_label_url_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_label_url(id);
+
+ALTER TABLE lt_track_track
+ ADD CONSTRAINT fk_lt_track_track_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_track_track(id);
+
+ALTER TABLE lt_track_url
+ ADD CONSTRAINT fk_lt_track_url_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_track_url(id);
+
+ALTER TABLE lt_url_url
+ ADD CONSTRAINT fk_lt_url_url_parent
+ FOREIGN KEY (parent)
+ REFERENCES lt_url_url(id);
+
+ALTER TABLE moderation_closed
+ ADD CONSTRAINT moderation_closed_fk_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE moderation_closed
+ ADD CONSTRAINT moderation_closed_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderation_closed
+ ADD CONSTRAINT moderation_closed_fk_language
+ FOREIGN KEY (language)
+ REFERENCES language(id);
+
+ALTER TABLE moderation_note_closed
+ ADD CONSTRAINT moderation_note_closed_fk_moderation
+ FOREIGN KEY (moderation)
+ REFERENCES moderation_closed(id);
+
+ALTER TABLE moderation_note_closed
+ ADD CONSTRAINT moderation_note_closed_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderation_open
+ ADD CONSTRAINT moderation_open_fk_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE moderation_open
+ ADD CONSTRAINT moderation_open_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderation_open
+ ADD CONSTRAINT moderation_open_fk_language
+ FOREIGN KEY (language)
+ REFERENCES language(id);
+
+ALTER TABLE moderation_note_open
+ ADD CONSTRAINT moderation_note_open_fk_moderation
+ FOREIGN KEY (moderation)
+ REFERENCES moderation_open(id);
+
+ALTER TABLE moderation_note_open
+ ADD CONSTRAINT moderation_note_open_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderator_preference
+ ADD CONSTRAINT moderator_preference_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderator_subscribe_artist
+ ADD CONSTRAINT modsubartist_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE moderator_subscribe_label
+ ADD CONSTRAINT modsublabel_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE editor_subscribe_editor
+ ADD CONSTRAINT editsubeditor_fk_moderator
+ FOREIGN KEY (editor)
+ REFERENCES moderator(id);
+
+ALTER TABLE editor_subscribe_editor
+ ADD CONSTRAINT editsubeditor_fk_moderator2
+ FOREIGN KEY (subscribededitor)
+ REFERENCES moderator(id);
+
+ALTER TABLE "PendingData"
+ ADD CONSTRAINT "PendingData_SeqId"
+ FOREIGN KEY ("SeqId")
+ REFERENCES "Pending" ("SeqId")
+ ON UPDATE CASCADE ON DELETE CASCADE;
+
+ALTER TABLE puid
+ ADD CONSTRAINT puid_fk_clientversion
+ FOREIGN KEY (version)
+ REFERENCES clientversion(id);
+
+ALTER TABLE puidjoin
+ ADD CONSTRAINT puidjoin_fk_track
+ FOREIGN KEY (track)
+ REFERENCES track(id);
+
+ALTER TABLE puidjoin
+ ADD CONSTRAINT puidjoin_fk_puid
+ FOREIGN KEY (puid)
+ REFERENCES puid(id);
+
+ALTER TABLE puidjoin_stat
+ ADD CONSTRAINT puidjoin_stat_fk_puidjoin
+ FOREIGN KEY (puidjoin_id)
+ REFERENCES puidjoin(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE puid_stat
+ ADD CONSTRAINT puid_stat_fk_puid
+ FOREIGN KEY (puid_id)
+ REFERENCES puid(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE release
+ ADD CONSTRAINT release_fk_album
+ FOREIGN KEY (album)
+ REFERENCES album(id);
+
+ALTER TABLE release
+ ADD CONSTRAINT release_fk_country
+ FOREIGN KEY (country)
+ REFERENCES country(id);
+
+ALTER TABLE release
+ ADD CONSTRAINT release_fk_label
+ FOREIGN KEY (label)
+ REFERENCES label(id);
+
+ALTER TABLE release_group
+ ADD CONSTRAINT release_group_fk_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE release_group_meta
+ ADD CONSTRAINT release_group_meta_fk_id
+ FOREIGN KEY (id)
+ REFERENCES release_group(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE release_groupwords
+ ADD CONSTRAINT release_groupwords_fk_release_groupid
+ FOREIGN KEY (release_groupid)
+ REFERENCES release_group (id)
+ ON DELETE CASCADE;
+
+ALTER TABLE release_tag
+ ADD CONSTRAINT fk_release_tag_release
+ FOREIGN KEY (release)
+ REFERENCES album(id);
+
+ALTER TABLE release_tag
+ ADD CONSTRAINT fk_release_tag_tag
+ FOREIGN KEY (tag)
+ REFERENCES tag(id);
+
+ALTER TABLE tag_relation
+ ADD CONSTRAINT tag_relation_fk_tag1
+ FOREIGN KEY (tag1)
+ REFERENCES tag(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE tag_relation
+ ADD CONSTRAINT tag_relation_fk_tag2
+ FOREIGN KEY (tag2)
+ REFERENCES tag(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE track
+ ADD CONSTRAINT track_fk_artist
+ FOREIGN KEY (artist)
+ REFERENCES artist(id);
+
+ALTER TABLE track_meta
+ ADD CONSTRAINT fk_track_meta_track
+ FOREIGN KEY (id)
+ REFERENCES track(id)
+ ON DELETE CASCADE;
+
+ALTER TABLE track_tag
+ ADD CONSTRAINT fk_track_tag_track
+ FOREIGN KEY (track)
+ REFERENCES track(id);
+
+ALTER TABLE track_tag
+ ADD CONSTRAINT fk_track_tag_tag
+ FOREIGN KEY (tag)
+ REFERENCES tag(id);
+
+ALTER TABLE trackwords
+ ADD CONSTRAINT trackwords_fk_trackid
+ FOREIGN KEY (trackid)
+ REFERENCES track (id)
+ ON DELETE CASCADE;
+
+ALTER TABLE vote_closed
+ ADD CONSTRAINT vote_closed_fk_moderation
+ FOREIGN KEY (moderation)
+ REFERENCES moderation_closed(id);
+
+ALTER TABLE vote_closed
+ ADD CONSTRAINT vote_closed_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE vote_open
+ ADD CONSTRAINT vote_open_fk_moderation
+ FOREIGN KEY (moderation)
+ REFERENCES moderation_open(id);
+
+ALTER TABLE vote_open
+ ADD CONSTRAINT vote_open_fk_moderator
+ FOREIGN KEY (moderator)
+ REFERENCES moderator(id);
+
+ALTER TABLE album
+ ADD CONSTRAINT album_fk_language
+ FOREIGN KEY (language)
+ REFERENCES language(id);
+
+ALTER TABLE album
+ ADD CONSTRAINT album_fk_script
+ FOREIGN KEY (script)
+ REFERENCES script(id);
+
+ALTER TABLE script_language
+ ADD CONSTRAINT script_language_fk_language
+ FOREIGN KEY (language)
+ REFERENCES language(id);
+
+ALTER TABLE script_language
+ ADD CONSTRAINT script_language_fk_script
+ FOREIGN KEY (script)
+ REFERENCES script(id);
+
+-- vi: set ts=4 sw=4 et :
659 sql/CreateFunctions.sql
@@ -0,0 +1,659 @@
+\set ON_ERROR_STOP 1
+
+--'-----------------------------------------------------------------
+-- The join(VARCHAR) aggregate
+--'-----------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION join_append(VARCHAR, VARCHAR)
+RETURNS VARCHAR AS '
+DECLARE
+ state ALIAS FOR $1;
+ value ALIAS FOR $2;
+BEGIN
+ IF (value IS NULL) THEN RETURN state; END IF;
+ IF (state IS NULL) THEN
+ RETURN value;
+ ELSE
+ RETURN(state || '' '' || value);
+ END IF;
+END;
+' LANGUAGE 'plpgsql';
+
+CREATE AGGREGATE join(BASETYPE = VARCHAR, SFUNC=join_append, STYPE=VARCHAR);
+
+--'-----------------------------------------------------------------
+-- Populate the albummeta table, one-to-one join with album.
+-- All columns are non-null integers, except firstreleasedate
+-- which is CHAR(10) WITH NULL
+--'-----------------------------------------------------------------
+
+create or replace function fill_album_meta () returns integer as '
+declare
+
+ table_count integer;
+
+begin
+
+ raise notice ''Truncating table albummeta'';
+ truncate table albummeta;
+
+ raise notice ''Counting tracks'';
+ create temporary table albummeta_tracks as select album.id, count(albumjoin.album)
+ from album left join albumjoin on album.id = albumjoin.album group by album.id;
+
+ raise notice ''Counting discids'';
+ create temporary table albummeta_discids as select album.id, count(album_cdtoc.album)
+ from album left join album_cdtoc on album.id = album_cdtoc.album group by album.id;
+
+ raise notice ''Counting puids'';
+ create temporary table albummeta_puids as select album.id, count(puidjoin.track)
+ from album, albumjoin left join puidjoin on albumjoin.track = puidjoin.track
+ where album.id = albumjoin.album group by album.id;
+
+ raise notice ''Finding first release dates'';
+ CREATE TEMPORARY TABLE albummeta_firstreleasedate AS
+ SELECT album AS id, MIN(releasedate)::CHAR(10) AS firstreleasedate
+ FROM release
+ GROUP BY album;
+
+ raise notice ''Filling albummeta table'';
+ insert into albummeta (id, tracks, discids, puids, firstreleasedate, asin, coverarturl, dateadded, lastupdate)
+ select a.id,
+ COALESCE(t.count, 0) AS tracks,
+ COALESCE(d.count, 0) AS discids,
+ COALESCE(p.count, 0) AS puids,
+ r.firstreleasedate,
+ aws.asin,
+ aws.coverarturl,
+ timestamp ''1970-01-01 00:00:00-00'',
+ NULL
+ FROM album a
+ LEFT JOIN albummeta_tracks t ON t.id = a.id
+ LEFT JOIN albummeta_discids d ON d.id = a.id
+ LEFT JOIN albummeta_puids p ON p.id = a.id
+ LEFT JOIN albummeta_firstreleasedate r ON r.id = a.id
+ LEFT JOIN album_amazon_asin aws on aws.album = a.id
+ ;
+
+ drop table albummeta_tracks;
+ drop table albummeta_discids;
+ drop table albummeta_puids;
+ drop table albummeta_firstreleasedate;
+
+ return 1;
+
+end;
+' language 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Keep rows in albummeta in sync with album
+--'-----------------------------------------------------------------
+
+create or replace function insert_album_meta () returns TRIGGER as $$
+begin
+ insert into albummeta (id, tracks, discids, puids, lastupdate) values (NEW.id, 0, 0, 0, now());
+ insert into album_amazon_asin (album, lastupdate) values (NEW.id, '1970-01-01 00:00:00');
+ PERFORM propagate_lastupdate(NEW.id, CAST('album' AS name));
+ UPDATE release_group_meta SET releasecount = releasecount + 1 WHERE id=NEW.release_group;
+
+ return NEW;
+end;
+$$ language 'plpgsql';
+
+create or replace function update_album_meta () returns TRIGGER as $$
+begin
+ IF (NEW.name != OLD.name)
+ THEN
+ UPDATE album_amazon_asin SET lastupdate = '1970-01-01 00:00:00' WHERE album = NEW.id;
+ END IF;
+ IF (NEW.release_group != OLD.release_group)
+ THEN
+ PERFORM set_release_group_firstreleasedate(OLD.release_group);
+ PERFORM set_release_group_firstreleasedate(NEW.release_group);
+ UPDATE release_group_meta SET releasecount = releasecount - 1 WHERE id=OLD.release_group;
+ UPDATE release_group_meta SET releasecount = releasecount + 1 WHERE id=NEW.release_group;
+ END IF;
+ IF (NEW.modpending = OLD.modpending)
+ THEN
+ UPDATE albummeta SET lastupdate = now() WHERE id = NEW.id;
+ PERFORM propagate_lastupdate(NEW.id, CAST('album' AS name));
+ END IF;
+ return NULL;
+end;
+$$ language 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Keep rows in <entity>_meta table in sync with table <entity>
+-- Deletion is done by cascade with foreign keys
+--'-----------------------------------------------------------------
+
+create or replace function a_iu_entity () returns TRIGGER as $$
+begin
+ IF (TG_OP = 'INSERT')
+ THEN
+ EXECUTE 'INSERT INTO ' || TG_RELNAME || '_meta (id) VALUES (' || NEW.id || ')';
+ PERFORM propagate_lastupdate(NEW.id, TG_RELNAME);
+ ELSIF (TG_OP = 'UPDATE')
+ THEN
+ IF (NEW.modpending = OLD.modpending)
+ THEN
+ IF (TG_RELNAME != 'track')
+ THEN
+ EXECUTE 'UPDATE ' || TG_RELNAME || '_meta SET lastupdate = now() WHERE id = ' || NEW.id;
+ END IF;
+ PERFORM propagate_lastupdate(NEW.id, TG_RELNAME);
+ END IF;
+ END IF;
+ RETURN NULL;
+end;
+$$ language 'plpgsql';
+
+create or replace function b_del_entity () returns TRIGGER as $$
+begin
+ IF (TG_RELNAME = 'album')
+ THEN
+ PERFORM set_release_group_firstreleasedate(OLD.release_group);
+ UPDATE release_group_meta SET releasecount = releasecount - 1 WHERE id=OLD.release_group;
+ END IF;
+ PERFORM propagate_lastupdate(OLD.id, TG_RELNAME);
+ RETURN OLD;
+end;
+$$ language 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Propagates changes on entity to linked entities
+--'-----------------------------------------------------------------
+create or replace function propagate_lastupdate (entity_id integer, relname name) returns VOID as $$
+begin
+
+--- This function caused the entire database to slow to a crawl and has been removed for now.
+--- This functionality will have to be carefully re-considered in the future.
+
+end;
+$$ language 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Changes to albumjoin could cause changes to albummeta.tracks
+-- and/or albummeta.puids and/or albummeta.puids
+--'-----------------------------------------------------------------
+
+create or replace function a_ins_albumjoin () returns trigger as $$
+begin
+ UPDATE albummeta
+ SET tracks = tracks + 1,
+ puids = puids + (SELECT COUNT(*) FROM puidjoin WHERE track = NEW.track)
+ WHERE id = NEW.album;
+ PERFORM propagate_lastupdate(NEW.track, CAST('track' AS name));
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+--'--
+create or replace function a_upd_albumjoin () returns trigger as $$
+begin
+ if NEW.album = OLD.album AND NEW.track = OLD.track
+ then
+ -- Sequence has been changed
+ IF (NEW.modpending = OLD.modpending)
+ THEN
+ PERFORM propagate_lastupdate(OLD.track, CAST('track' AS name));
+ END IF;
+
+ elsif NEW.track = OLD.track
+ then
+ -- A track is moved from an album to another one
+ UPDATE albummeta
+ SET tracks = tracks - 1,
+ puids = puids - (SELECT COUNT(*) FROM puidjoin WHERE track = OLD.track),
+ lastupdate = now()
+ WHERE id = OLD.album;
+ -- For the old album we can't do anything better than propagete lastupdate at the album level
+ PERFORM propagate_lastupdate(OLD.album, CAST('album' AS name));
+
+ UPDATE albummeta
+ SET tracks = tracks + 1,
+ puids = puids + (SELECT COUNT(*) FROM puidjoin WHERE track = NEW.track)
+ WHERE id = NEW.album;
+ PERFORM propagate_lastupdate(NEW.track, CAST('track' AS name));
+
+ elsif NEW.album = OLD.album
+ then
+ -- TODO: should not happen yet
+ end if;
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+--'--
+create or replace function a_del_albumjoin () returns trigger as $$
+begin
+ UPDATE albummeta
+ SET tracks = tracks - 1,
+ puids = puids - (SELECT COUNT(*) FROM puidjoin WHERE track = OLD.track)
+ WHERE id = OLD.album;
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+
+create or replace function b_del_albumjoin () returns TRIGGER as $$
+begin
+ PERFORM propagate_lastupdate(OLD.track, CAST('track' AS name));
+ RETURN OLD;
+end;
+$$ language 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Changes to album_cdtoc could cause changes to albummeta.discids
+--'-----------------------------------------------------------------
+
+create or replace function a_ins_album_cdtoc () returns trigger as $$
+begin
+ UPDATE albummeta
+ SET discids = discids + 1,
+ lastupdate = now()
+ WHERE id = NEW.album;
+ PERFORM propagate_lastupdate(NEW.album, CAST('album' AS name));
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+--'--
+create or replace function a_upd_album_cdtoc () returns trigger as $$
+begin
+ if NEW.album = OLD.album
+ then
+ return NULL;
+ end if;
+
+ UPDATE albummeta
+ SET discids = discids - 1,
+ lastupdate = now()
+ WHERE id = OLD.album;
+ PERFORM propagate_lastupdate(OLD.album, CAST('album' AS name));
+
+ UPDATE albummeta
+ SET discids = discids + 1,
+ lastupdate = now()
+ WHERE id = NEW.album;
+ PERFORM propagate_lastupdate(NEW.album, CAST('album' AS name));
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+--'--
+create or replace function a_del_album_cdtoc () returns trigger as $$
+begin
+ UPDATE albummeta
+ SET discids = discids - 1,
+ lastupdate = now()
+ WHERE id = OLD.album;
+ PERFORM propagate_lastupdate(OLD.album, CAST('album' AS name));
+
+ return NULL;
+end;
+$$ language 'plpgsql';
+
+
+--'-----------------------------------------------------------------
+-- Changes to puidjoin could cause changes to albummeta.puids
+--'-----------------------------------------------------------------
+
+create or replace function a_ins_puidjoin () returns trigger as '
+begin
+ UPDATE albummeta
+ SET puids = puids + 1
+ WHERE id IN (SELECT album FROM albumjoin WHERE track = NEW.track);
+
+ return NULL;
+end;
+' language 'plpgsql';
+--'--
+create or replace function a_upd_puidjoin () returns trigger as '
+begin
+ if NEW.track = OLD.track
+ then
+ return NULL;
+ end if;
+
+ UPDATE albummeta
+ SET puids = puids - 1
+ WHERE id IN (SELECT album FROM albumjoin WHERE track = OLD.track);
+
+ UPDATE albummeta
+ SET puids = puids + 1
+ WHERE id IN (SELECT album FROM albumjoin WHERE track = NEW.track);
+
+ return NULL;
+end;
+' language 'plpgsql';
+--'--
+create or replace function a_del_puidjoin () returns trigger as '
+begin
+ UPDATE albummeta
+ SET puids = puids - 1
+ WHERE id IN (SELECT album FROM albumjoin WHERE track = OLD.track);
+
+ return NULL;
+end;
+' language 'plpgsql';
+--'-----------------------------------------------------------------
+-- When a moderation closes, move rows from _open to _closed
+--'-----------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION after_update_moderation_open () RETURNS TRIGGER AS '
+begin
+
+ if (OLD.status IN (1,8) and NEW.status NOT IN (1,8)) -- STATUS_OPEN, STATUS_TOBEDELETED
+ then
+ -- Create moderation_closed record
+ INSERT INTO moderation_closed SELECT * FROM moderation_open WHERE id = NEW.id;
+ -- and update the closetime
+ UPDATE moderation_closed SET closetime = NOW() WHERE id = NEW.id;
+
+ -- Copy notes
+ INSERT INTO moderation_note_closed
+ SELECT * FROM moderation_note_open
+ WHERE moderation = NEW.id;
+
+ -- Copy votes
+ INSERT INTO vote_closed
+ SELECT * FROM vote_open
+ WHERE moderation = NEW.id;
+
+ -- Delete the _open records
+ DELETE FROM vote_open WHERE moderation = NEW.id;
+ DELETE FROM moderation_note_open WHERE moderation = NEW.id;
+ DELETE FROM moderation_open WHERE id = NEW.id;
+ end if;
+
+ return NEW;
+end;
+' LANGUAGE 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Ensure release.releasedate is always valid
+--'-----------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION before_insertupdate_release () RETURNS TRIGGER AS '
+DECLARE
+ y CHAR(4);
+ m CHAR(2);
+ d CHAR(2);
+ teststr VARCHAR(10);
+ testdate DATE;
+BEGIN
+ -- Check that the releasedate looks like this: yyyy-mm-dd
+ IF (NOT(NEW.releasedate ~ ''^[0-9][0-9][0-9][0-9]-[0-9][0-9]-[0-9][0-9]$''))
+ THEN
+ RAISE EXCEPTION ''Invalid release date specification'';
+ END IF;
+
+ y := SUBSTR(NEW.releasedate, 1, 4);
+ m := SUBSTR(NEW.releasedate, 6, 2);
+ d := SUBSTR(NEW.releasedate, 9, 2);
+
+ -- Disallow yyyy-00-dd
+ IF (m = ''00'' AND d != ''00'')
+ THEN
+ RAISE EXCEPTION ''Invalid release date specification'';
+ END IF;
+
+ -- Check that the y/m/d combination is valid (e.g. disallow 2003-02-31)
+ IF (m = ''00'') THEN m:= ''01''; END IF;
+ IF (d = ''00'') THEN d:= ''01''; END IF;
+ teststr := ( y || ''-'' || m || ''-'' || d );
+ -- TO_DATE allows 2003-08-32 etc (it becomes 2003-09-01)
+ -- So we will use the ::date cast, which catches this error
+ testdate := teststr;
+
+ RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Maintain albummeta.firstreleasedate
+--'-----------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION set_release_group_firstreleasedate(release_group_id INTEGER)
+RETURNS VOID AS $$
+BEGIN
+ UPDATE release_group_meta SET firstreleasedate = (
+ SELECT MIN(firstreleasedate) FROM albummeta, album WHERE album.id = albummeta.id
+ AND release_group = release_group_id AND firstreleasedate <> '0000-00-00' AND firstreleasedate IS NOT NULL
+ ) WHERE id = release_group_id;
+ RETURN;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION set_album_firstreleasedate(INTEGER)
+RETURNS VOID AS $$
+DECLARE
+ release_group_id INTEGER;
+BEGIN
+ UPDATE albummeta SET firstreleasedate = (
+ SELECT MIN(releasedate) FROM release WHERE album = $1
+ AND releasedate <> '0000-00-00' AND releasedate IS NOT NULL
+ ), lastupdate = now() WHERE id = $1;
+ release_group_id := (SELECT release_group FROM album WHERE id = $1);
+ EXECUTE set_release_group_firstreleasedate(release_group_id);
+ RETURN;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_ins_release () RETURNS TRIGGER AS $$
+BEGIN
+ EXECUTE set_album_firstreleasedate(NEW.album);
+ PERFORM propagate_lastupdate(NEW.id, CAST('release' AS name));
+ RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_upd_release () RETURNS TRIGGER AS $$
+BEGIN
+ IF (OLD.modpending = NEW.modpending)
+ THEN
+ EXECUTE set_album_firstreleasedate(NEW.album);
+ PERFORM propagate_lastupdate(NEW.id, CAST('release' AS name));
+
+ IF (OLD.album != NEW.album)
+ THEN
+ EXECUTE set_album_firstreleasedate(OLD.album);
+ -- propagate_lastupdate not called since OLD.album is probably
+ -- being merged in NEW.album
+ END IF;
+ END IF;
+ RETURN NEW;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_del_release () RETURNS TRIGGER AS $$
+BEGIN
+ EXECUTE set_album_firstreleasedate(OLD.album);
+ RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+--'-----------------------------------------------------------------
+-- Changes to album_amazon_asin should cause changes to albummeta.asin
+--'-----------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION set_album_asin(INTEGER)
+RETURNS VOID AS '
+BEGIN
+ UPDATE albummeta SET coverarturl = (
+ SELECT coverarturl FROM album_amazon_asin WHERE album = $1
+ ), asin = (
+ SELECT asin FROM album_amazon_asin WHERE album = $1
+ ) WHERE id = $1
+ -- Test if album still exists (sanity check)
+ AND EXISTS (SELECT 1 FROM album where id = $1);
+ RETURN;
+END;
+' LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_ins_album_amazon_asin () RETURNS TRIGGER AS '
+BEGIN
+ EXECUTE set_album_asin(NEW.album);
+ RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_upd_album_amazon_asin () RETURNS TRIGGER AS '
+BEGIN
+ EXECUTE set_album_asin(NEW.album);
+ IF (OLD.album != NEW.album)
+ THEN
+ EXECUTE set_album_asin(OLD.album);
+ END IF;
+ RETURN NEW;
+END;
+' LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_del_album_amazon_asin () RETURNS TRIGGER AS '
+BEGIN
+ EXECUTE set_album_asin(OLD.album);
+ RETURN OLD;
+END;
+' LANGUAGE 'plpgsql';
+
+--'-----------------------------------------------------------------------------------
+-- Changes to puid_stat/puidjoin_stat causes changes to puid.lookupcount/puidjoin.usecount
+--'-----------------------------------------------------------------------------------
+
+CREATE OR REPLACE FUNCTION a_idu_puid_stat () RETURNS trigger AS '
+BEGIN
+ IF (TG_OP = ''INSERT'' OR TG_OP = ''UPDATE'')
+ THEN
+ UPDATE puid SET lookupcount = (SELECT COALESCE(SUM(puid_stat.lookupcount), 0) FROM puid_stat WHERE puid_id = NEW.puid_id) WHERE id = NEW.puid_id;
+ IF (TG_OP = ''UPDATE'')
+ THEN
+ IF (NEW.puid_id != OLD.puid_id)
+ THEN
+ UPDATE puid SET lookupcount = (SELECT COALESCE(SUM(puid_stat.lookupcount), 0) FROM puid_stat WHERE puid_id = OLD.puid_id) WHERE id = OLD.puid_id;
+ END IF;
+ END IF;
+ ELSE
+ UPDATE puid SET lookupcount = (SELECT COALESCE(SUM(puid_stat.lookupcount), 0) FROM puid_stat WHERE puid_id = OLD.puid_id) WHERE id = OLD.puid_id;
+ END IF;
+
+ RETURN NULL;
+END;
+' LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION a_idu_puidjoin_stat () RETURNS trigger AS '
+BEGIN
+ IF (TG_OP = ''INSERT'' OR TG_OP = ''UPDATE'')
+ THEN
+ UPDATE puidjoin SET usecount = (SELECT COALESCE(SUM(puidjoin_stat.usecount), 0) FROM puidjoin_stat WHERE puidjoin_id = NEW.puidjoin_id) WHERE id = NEW.puidjoin_id;
+ IF (TG_OP = ''UPDATE'')
+ THEN
+ IF (NEW.puidjoin_id != OLD.puidjoin_id)
+ THEN
+ UPDATE puidjoin SET usecount = (SELECT COALESCE(SUM(puidjoin_stat.usecount), 0) FROM puidjoin_stat WHERE puidjoin_id = OLD.puidjoin_id) WHERE id = OLD.puidjoin_id;
+ END IF;
+ END IF;
+ ELSE
+ UPDATE puidjoin SET usecount = (SELECT COALESCE(SUM(puidjoin_stat.usecount), 0) FROM puidjoin_stat WHERE puidjoin_id = OLD.puidjoin_id) WHERE id = OLD.puidjoin_id;
+ END IF;
+
+ RETURN NULL;
+END;
+' LANGUAGE 'plpgsql';
+
+--'-----------------------------------------------------------------------------------
+-- Maintain Tags refcount
+--'-----------------------------------------------------------------------------------
+
+create or replace function a_ins_tag () returns trigger as '
+begin
+ UPDATE tag
+ SET refcount = refcount + 1
+ WHERE id = NEW.tag;
+
+ return NULL;
+end;
+' language 'plpgsql';
+
+create or replace function a_del_tag () returns trigger as '
+declare
+ ref_count integer;
+begin
+
+ SELECT INTO ref_count refcount FROM tag WHERE id = OLD.tag;
+ IF ref_count = 1 THEN
+ DELETE FROM tag WHERE id = OLD.tag;
+ ELSE
+ UPDATE tag
+ SET refcount = refcount - 1
+ WHERE id = OLD.tag;
+ END IF;
+
+ return NULL;
+end;
+' language 'plpgsql';
+
+CREATE OR REPLACE FUNCTION from_hex(t text) RETURNS integer
+ AS $$
+DECLARE
+ r RECORD;
+BEGIN
+ FOR r IN EXECUTE 'SELECT x'''||t||'''::integer AS hex' LOOP
+ RETURN r.hex;
+ END LOOP;
+END
+$$ LANGUAGE plpgsql IMMUTABLE STRICT;
+
+-- NameSpace_URL = '6ba7b8119dad11d180b400c04fd430c8'
+CREATE OR REPLACE FUNCTION generate_uuid_v3(namespace varchar, name varchar) RETURNS varchar
+ AS $$
+DECLARE
+ value varchar(36);
+ bytes varchar;
+BEGIN
+ bytes = md5(decode(namespace, 'hex') || decode(name, 'escape'));
+ value = substr(bytes, 1+0, 8);
+ value = value || '-';
+ value = value || substr(bytes, 1+2*4, 4);
+ value = value || '-';
+ value = value || lpad(to_hex((from_hex(substr(bytes, 1+2*6, 2)) & 15) | 48), 2, '0');
+ value = value || substr(bytes, 1+2*7, 2);
+ value = value || '-';
+ value = value || lpad(to_hex((from_hex(substr(bytes, 1+2*8, 2)) & 63) | 128), 2, '0');
+ value = value || substr(bytes, 1+2*9, 2);
+ value = value || '-';
+ value = value || substr(bytes, 1+2*10, 12);
+ return value;
+END;
+$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT;
+
+CREATE OR REPLACE FUNCTION generate_uuid_v4() RETURNS varchar
+ AS $$
+DECLARE
+ value VARCHAR(36);
+BEGIN
+ value = lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || '-';
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || '-';
+ value = value || lpad((to_hex((ceil(random() * 255)::int & 15) | 64)), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || '-';
+ value = value || lpad((to_hex((ceil(random() * 255)::int & 63) | 128)), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || '-';
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ value = value || lpad(to_hex(ceil(random() * 255)::int), 2, '0');
+ RETURN value;
+END;
+$$ LANGUAGE 'plpgsql';
+
+--'-- vi: set ts=4 sw=4 et :
236 sql/CreateIndexes.sql
@@ -0,0 +1,236 @@
+\set ON_ERROR_STOP 1
+
+-- No BEGIN/COMMIT here. Each index is created in its own transaction;
+-- this is mainly because if you're setting up a big database, it
+-- could get really annoying if it takes a long time to create the indexes,
+-- only for the last one to fail and the whole lot gets rolled back.
+-- It should also be more efficient, of course.
+
+-- Alphabetical order by table
+
+CREATE INDEX album_artistindex ON album (artist);
+CREATE UNIQUE INDEX album_gidindex ON album (gid);
+CREATE INDEX album_nameindex ON album (name);
+CREATE INDEX album_pageindex ON album (page);
+CREATE INDEX album_release_groupindex ON album (release_group);
+
+CREATE INDEX album_amazon_asin_asin ON album_amazon_asin (asin);
+CREATE INDEX albummeta_lastupdate ON albummeta (lastupdate);
+
+CREATE UNIQUE INDEX album_cdtoc_albumcdtoc ON album_cdtoc (album, cdtoc);
+
+CREATE INDEX albumjoin_albumindex ON albumjoin (album);
+CREATE UNIQUE INDEX albumjoin_albumtrack ON albumjoin (album, track);
+CREATE INDEX albumjoin_trackindex ON albumjoin (track);
+
+CREATE INDEX albumwords_albumidindex ON albumwords (albumid);
+
+CREATE INDEX annotation_rowidindex ON annotation (rowid);
+CREATE UNIQUE INDEX annotation_moderationindex ON annotation (moderation);
+
+CREATE UNIQUE INDEX artist_gidindex ON artist (gid);
+CREATE INDEX artist_nameindex ON artist (name);
+CREATE INDEX artist_lowernameindex ON artist (lower(name));
+CREATE INDEX artist_pageindex ON artist (page);
+CREATE INDEX artist_sortnameindex ON artist (sortname);
+
+CREATE INDEX artist_meta_lastupdate ON artist_meta (lastupdate);
+
+CREATE INDEX artist_relation_artist ON artist_relation (artist);
+CREATE INDEX artist_relation_ref ON artist_relation (ref);
+
+CREATE UNIQUE INDEX artistalias_nameindex ON artistalias (name);
+CREATE INDEX artistalias_refindex ON artistalias (ref);
+
+CREATE INDEX artist_tag_idx_artist ON artist_tag (artist);
+CREATE INDEX artist_tag_idx_tag ON artist_tag (tag);
+
+CREATE INDEX artistwords_artistidindex ON artistwords (artistid);
+
+CREATE INDEX cdtoc_discid ON cdtoc (discid);
+CREATE INDEX cdtoc_freedbid ON cdtoc (freedbid);
+CREATE INDEX cdtoc_trackoffset ON cdtoc (trackoffset);
+CREATE UNIQUE INDEX cdtoc_toc ON cdtoc (trackcount, leadoutoffset, trackoffset);
+
+CREATE UNIQUE INDEX clientversion_version ON clientversion (version);
+
+CREATE UNIQUE INDEX country_isocode ON country (isocode);
+CREATE UNIQUE INDEX country_name ON country (name);
+
+CREATE INDEX currentstat_name ON currentstat (name);
+
+CREATE UNIQUE INDEX isrc_track_isrc ON isrc (track, isrc);
+CREATE INDEX isrc_isrc ON isrc (isrc);
+
+CREATE INDEX historicalstat_date ON historicalstat (snapshotdate);
+CREATE INDEX historicalstat_name_snapshotdate ON historicalstat (name, snapshotdate);
+
+CREATE INDEX gid_redirect_newid ON gid_redirect (newid);
+
+CREATE UNIQUE INDEX l_album_album_idx_uniq ON l_album_album (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_album_artist_idx_uniq ON l_album_artist (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_album_label_idx_uniq ON l_album_label (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_album_track_idx_uniq ON l_album_track (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_album_url_idx_uniq ON l_album_url (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_artist_artist_idx_uniq ON l_artist_artist (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_artist_label_idx_uniq ON l_artist_label (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_artist_track_idx_uniq ON l_artist_track (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_artist_url_idx_uniq ON l_artist_url (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_label_label_idx_uniq ON l_label_label (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_label_track_idx_uniq ON l_label_track (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_label_url_idx_uniq ON l_label_url (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_track_track_idx_uniq ON l_track_track (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_track_url_idx_uniq ON l_track_url (link0, link1, link_type, begindate, enddate);
+CREATE UNIQUE INDEX l_url_url_idx_uniq ON l_url_url (link0, link1, link_type, begindate, enddate);
+
+CREATE INDEX l_album_album_idx_link1 ON l_album_album (link1);
+CREATE INDEX l_album_artist_idx_link1 ON l_album_artist (link1);
+CREATE INDEX l_album_label_idx_link1 ON l_album_label (link1);
+CREATE INDEX l_album_track_idx_link1 ON l_album_track (link1);
+CREATE INDEX l_album_url_idx_link1 ON l_album_url (link1);
+CREATE INDEX l_artist_artist_idx_link1 ON l_artist_artist (link1);
+CREATE INDEX l_artist_label_idx_link1 ON l_artist_label (link1);
+CREATE INDEX l_artist_track_idx_link1 ON l_artist_track (link1);
+CREATE INDEX l_artist_url_idx_link1 ON l_artist_url (link1);
+CREATE INDEX l_label_label_idx_link1 ON l_label_label (link1);
+CREATE INDEX l_label_track_idx_link1 ON l_label_track (link1);
+CREATE INDEX l_label_url_idx_link1 ON l_label_url (link1);
+CREATE INDEX l_track_track_idx_link1 ON l_track_track (link1);
+CREATE INDEX l_track_url_idx_link1 ON l_track_url (link1);
+CREATE INDEX l_url_url_idx_link1 ON l_url_url (link1);
+
+CREATE UNIQUE INDEX label_gidindex ON label (gid);
+CREATE INDEX label_nameindex ON label (name);
+CREATE INDEX label_pageindex ON label (page);
+CREATE INDEX labelwords_labelidindex ON labelwords (labelid);
+CREATE INDEX labelalias_nameindex ON labelalias (name);
+CREATE INDEX labelalias_refindex ON labelalias (ref);
+
+CREATE INDEX label_meta_lastupdate ON label_meta (lastupdate);
+
+CREATE INDEX label_tag_idx_label ON label_tag (label);
+CREATE INDEX label_tag_idx_tag ON label_tag (tag);
+
+CREATE UNIQUE INDEX language_isocode_3b ON language (isocode_3b);
+CREATE UNIQUE INDEX language_isocode_3t ON language (isocode_3t);
+CREATE UNIQUE INDEX language_isocode_2 ON language (isocode_2);
+
+CREATE INDEX link_attribute_idx_link_type ON link_attribute (link, link_type);
+CREATE UNIQUE INDEX link_attribute_type_idx_parent_name ON link_attribute_type (parent, name);
+CREATE INDEX link_attribute_type_idx_name ON link_attribute_type (name);
+
+CREATE UNIQUE INDEX lt_album_album_idx_mbid ON lt_album_album (mbid);
+CREATE UNIQUE INDEX lt_album_album_idx_parent_name ON lt_album_album (parent, name);
+CREATE UNIQUE INDEX lt_album_artist_idx_mbid ON lt_album_artist (mbid);
+CREATE UNIQUE INDEX lt_album_artist_idx_parent_name ON lt_album_artist (parent, name);
+CREATE UNIQUE INDEX lt_album_label_idx_mbid ON lt_album_label (mbid);
+CREATE UNIQUE INDEX lt_album_label_idx_parent_name ON lt_album_label (parent, name);
+CREATE UNIQUE INDEX lt_album_track_idx_mbid ON lt_album_track (mbid);
+CREATE UNIQUE INDEX lt_album_track_idx_parent_name ON lt_album_track (parent, name);
+CREATE UNIQUE INDEX lt_album_url_idx_mbid ON lt_album_url (mbid);
+CREATE UNIQUE INDEX lt_album_url_idx_parent_name ON lt_album_url (parent, name);
+CREATE UNIQUE INDEX lt_artist_artist_idx_mbid ON lt_artist_artist (mbid);
+CREATE UNIQUE INDEX lt_artist_artist_idx_parent_name ON lt_artist_artist (parent, name);
+CREATE UNIQUE INDEX lt_artist_label_idx_mbid ON lt_artist_label (mbid);
+CREATE UNIQUE INDEX lt_artist_label_idx_parent_name ON lt_artist_label (parent, name);
+CREATE UNIQUE INDEX lt_artist_track_idx_mbid ON lt_artist_track (mbid);
+CREATE UNIQUE INDEX lt_artist_track_idx_parent_name ON lt_artist_track (parent, name);
+CREATE UNIQUE INDEX lt_artist_url_idx_mbid ON lt_artist_url (mbid);
+CREATE UNIQUE INDEX lt_artist_url_idx_parent_name ON lt_artist_url (parent, name);
+CREATE UNIQUE INDEX lt_label_label_idx_mbid ON lt_label_label (mbid);
+CREATE UNIQUE INDEX lt_label_label_idx_parent_name ON lt_label_label (parent, name);
+CREATE UNIQUE INDEX lt_label_track_idx_mbid ON lt_label_track (mbid);
+CREATE UNIQUE INDEX lt_label_track_idx_parent_name ON lt_label_track (parent, name);
+CREATE UNIQUE INDEX lt_label_url_idx_mbid ON lt_label_url (mbid);
+CREATE UNIQUE INDEX lt_label_url_idx_parent_name ON lt_label_url (parent, name);
+CREATE UNIQUE INDEX lt_track_track_idx_mbid ON lt_track_track (mbid);
+CREATE UNIQUE INDEX lt_track_track_idx_parent_name ON lt_track_track (parent, name);
+CREATE UNIQUE INDEX lt_track_url_idx_mbid ON lt_track_url (mbid);
+CREATE UNIQUE INDEX lt_track_url_idx_parent_name ON lt_track_url (parent, name);
+CREATE UNIQUE INDEX lt_url_url_idx_mbid ON lt_url_url (mbid);
+CREATE UNIQUE INDEX lt_url_url_idx_parent_name ON lt_url_url (parent, name);
+
+CREATE INDEX moderation_closed_idx_artist ON moderation_closed (artist);
+CREATE INDEX moderation_closed_idx_opentime ON moderation_closed (opentime);
+CREATE INDEX moderation_closed_idx_expiretime ON moderation_closed (expiretime);
+CREATE INDEX moderation_closed_idx_closetime ON moderation_closed (closetime);
+CREATE INDEX moderation_closed_idx_moderator ON moderation_closed (moderator);
+CREATE INDEX moderation_closed_idx_rowid ON moderation_closed (rowid);
+CREATE INDEX moderation_closed_idx_status ON moderation_closed (status);
+CREATE INDEX moderation_closed_idx_language ON moderation_closed (language);
+
+CREATE INDEX moderation_note_closed_idx_moderation ON moderation_note_closed (moderation);
+
+CREATE INDEX moderation_note_open_idx_moderation ON moderation_note_open (moderation);
+
+CREATE INDEX moderation_open_idx_artist ON moderation_open (artist);
+CREATE INDEX moderation_open_idx_expiretime ON moderation_open (expiretime);
+CREATE INDEX moderation_open_idx_moderator ON moderation_open (moderator);
+CREATE INDEX moderation_open_idx_rowid ON moderation_open (rowid);
+CREATE INDEX moderation_open_idx_status ON moderation_open (status);
+CREATE INDEX moderation_open_idx_language ON moderation_open (language);
+
+CREATE UNIQUE INDEX moderator_nameindex ON moderator (name);
+CREATE INDEX moderator_emailindex ON moderator (email);
+
+CREATE UNIQUE INDEX moderator_preference_moderator_key ON moderator_preference (moderator, name);
+
+CREATE UNIQUE INDEX moderator_subscribe_artist_moderator_key ON moderator_subscribe_artist (moderator, artist);
+CREATE UNIQUE INDEX moderator_subscribe_label_moderator_key ON moderator_subscribe_label (moderator, label);
+CREATE UNIQUE INDEX editor_subscribe_editor_editor_key ON editor_subscribe_editor (editor, subscribededitor);
+
+CREATE INDEX "Pending_XID_Index" ON "Pending" ("XID");
+
+CREATE UNIQUE INDEX puid_puidindex ON puid (puid);
+
+CREATE UNIQUE INDEX puid_stat_puid_idindex ON puid_stat (puid_id, month_id);
+
+CREATE INDEX puidjoin_trackindex ON puidjoin (track);
+CREATE UNIQUE INDEX puidjoin_puidtrack ON puidjoin (puid, track);
+
+CREATE UNIQUE INDEX puidjoin_stat_puidjoin_idindex ON puidjoin_stat (puidjoin_id, month_id);
+
+CREATE INDEX release_album ON release (album);
+CREATE INDEX release_label ON release (label);
+CREATE INDEX release_releasedate ON release (releasedate);
+
+CREATE INDEX release_group_artistindex ON release_group (artist);
+CREATE UNIQUE INDEX release_group_gidindex ON release_group (gid);
+CREATE INDEX release_group_nameindex ON release_group (name);
+CREATE INDEX release_group_pageindex ON release_group (page);
+
+CREATE INDEX release_groupwords_release_groupidindex ON release_groupwords (release_groupid);
+
+CREATE INDEX release_tag_idx_release ON release_tag (release);
+CREATE INDEX release_tag_idx_tag ON release_tag (tag);
+
+CREATE UNIQUE INDEX script_isocode ON script (isocode);
+CREATE UNIQUE INDEX script_isonumber ON script (isonumber);
+
+CREATE UNIQUE INDEX script_language_sl ON script_language (script, language);
+
+CREATE UNIQUE INDEX stats_timestampindex ON stats (timestamp);
+
+CREATE UNIQUE INDEX tag_idx_name ON tag (name);
+
+CREATE INDEX track_artistindex ON track (artist);
+CREATE UNIQUE INDEX track_gidindex ON track (gid);
+CREATE INDEX track_nameindex ON track (name);
+
+CREATE INDEX track_tag_idx_track ON track_tag (track);
+CREATE INDEX track_tag_idx_tag ON track_tag (tag);
+
+CREATE INDEX trackwords_trackidindex ON trackwords (trackid);
+
+CREATE UNIQUE INDEX url_idx_gid ON url (gid);
+CREATE UNIQUE INDEX url_idx_url ON url (url);
+
+CREATE INDEX vote_closed_idx_moderation ON vote_closed (moderation);
+CREATE INDEX vote_closed_idx_moderator ON vote_closed (moderator);
+
+CREATE INDEX vote_open_idx_moderation ON vote_open (moderation);
+CREATE INDEX vote_open_idx_moderator ON vote_open (moderator);
+
+CREATE UNIQUE INDEX wordlist_wordindex ON wordlist (word);
+
+-- vi: set ts=4 sw=4 et :
45 sql/CreateLinkFKs.pl
@@ -0,0 +1,45 @@
+#!/usr/bin/perl -w
+# vi: set ts=4 sw=4 :
+
+use strict;
+
+print <<EOF;
+-- For each pair of entity types, there are four FKs to create:
+-- * lt.parent refers to lt.id
+-- * l.link_type refers to lt.id
+-- * l.link0 and l.link1
+
+EOF
+
+my @e = qw( album artist track url );
+for my $a (@e)
+{
+ for my $b (@e)
+ {
+ next unless $a le $b;
+
+ my $typetab = "lt_${a}_${b}";
+ my $linktab = "l_${a}_${b}";
+
+ print <<EOF;
+ALTER TABLE $typetab
+ ADD CONSTRAINT fk_${typetab}_parent
+ FOREIGN KEY (parent)
+ REFERENCES $typetab(id);
+ALTER TABLE $linktab
+ ADD CONSTRAINT fk_${linktab}_link_type
+ FOREIGN KEY (link_type)
+ REFERENCES $typetab(id);
+ALTER TABLE $linktab
+ ADD CONSTRAINT fk_${linktab}_link0
+ FOREIGN KEY (link0)
+ REFERENCES ${a}(id);
+ALTER TABLE $linktab
+ ADD CONSTRAINT fk_${linktab}_link1
+ FOREIGN KEY (link1)
+ REFERENCES ${b}(id);
+
+EOF
+ }
+}
+
100 sql/CreatePrimaryKeys.sql
@@ -0,0 +1,100 @@
+\set ON_ERROR_STOP 1
+
+-- Alphabetical order by table
+
+ALTER TABLE album ADD CONSTRAINT album_pkey PRIMARY KEY (id);
+ALTER TABLE albumjoin ADD CONSTRAINT albumjoin_pkey PRIMARY KEY (id);
+ALTER TABLE albummeta ADD CONSTRAINT albummeta_pkey PRIMARY KEY (id);
+ALTER TABLE album_amazon_asin ADD CONSTRAINT album_amazon_asin_pkey PRIMARY KEY (album);
+ALTER TABLE album_cdtoc ADD CONSTRAINT album_cdtoc_pkey PRIMARY KEY (id);
+ALTER TABLE albumwords ADD CONSTRAINT albumwords_pkey PRIMARY KEY (wordid, albumid);
+ALTER TABLE annotation ADD CONSTRAINT annotation_pkey PRIMARY KEY (id);
+ALTER TABLE artist ADD CONSTRAINT artist_pkey PRIMARY KEY (id);
+ALTER TABLE artist_meta ADD CONSTRAINT artist_meta_pkey PRIMARY KEY(id);
+ALTER TABLE artistalias ADD CONSTRAINT artistalias_pkey PRIMARY KEY (id);
+ALTER TABLE artist_relation ADD CONSTRAINT artist_relation_pkey PRIMARY KEY (id);
+ALTER TABLE artist_tag ADD CONSTRAINT artist_tag_pkey PRIMARY KEY (artist, tag);
+ALTER TABLE artistwords ADD CONSTRAINT artistwords_pkey PRIMARY KEY (wordid, artistid);
+ALTER TABLE automod_election ADD CONSTRAINT automod_election_pkey PRIMARY KEY (id);
+ALTER TABLE automod_election_vote ADD CONSTRAINT automod_election_vote_pkey PRIMARY KEY (id);
+ALTER TABLE cdtoc ADD CONSTRAINT cdtoc_pkey PRIMARY KEY (id);
+ALTER TABLE clientversion ADD CONSTRAINT clientversion_pkey PRIMARY KEY (id);
+ALTER TABLE country ADD CONSTRAINT country_pkey PRIMARY KEY (id);
+ALTER TABLE currentstat ADD CONSTRAINT currentstat_pkey PRIMARY KEY (id);
+ALTER TABLE isrc ADD CONSTRAINT isrc_pkey PRIMARY KEY (id);
+ALTER TABLE historicalstat ADD CONSTRAINT historicalstat_pkey PRIMARY KEY (id);
+ALTER TABLE gid_redirect ADD CONSTRAINT gid_redirect_pkey PRIMARY KEY (gid);
+ALTER TABLE l_album_album ADD CONSTRAINT l_album_album_pkey PRIMARY KEY (id);
+ALTER TABLE l_album_artist ADD CONSTRAINT l_album_artist_pkey PRIMARY KEY (id);
+ALTER TABLE l_album_label ADD CONSTRAINT l_album_label_pkey PRIMARY KEY (id);
+ALTER TABLE l_album_track ADD CONSTRAINT l_album_track_pkey PRIMARY KEY (id);
+ALTER TABLE l_album_url ADD CONSTRAINT l_album_url_pkey PRIMARY KEY (id);
+ALTER TABLE l_artist_artist ADD CONSTRAINT l_artist_artist_pkey PRIMARY KEY (id);
+ALTER TABLE l_artist_label ADD CONSTRAINT l_artist_label_pkey PRIMARY KEY (id);
+ALTER TABLE l_artist_track ADD CONSTRAINT l_artist_track_pkey PRIMARY KEY (id);
+ALTER TABLE l_artist_url ADD CONSTRAINT l_artist_url_pkey PRIMARY KEY (id);
+ALTER TABLE l_label_label ADD CONSTRAINT l_label_label_pkey PRIMARY KEY (id);
+ALTER TABLE l_label_track ADD CONSTRAINT l_label_track_pkey PRIMARY KEY (id);
+ALTER TABLE l_label_url ADD CONSTRAINT l_label_url_pkey PRIMARY KEY (id);
+ALTER TABLE l_track_track ADD CONSTRAINT l_track_track_pkey PRIMARY KEY (id);
+ALTER TABLE l_track_url ADD CONSTRAINT l_track_url_pkey PRIMARY KEY (id);
+ALTER TABLE l_url_url ADD CONSTRAINT l_url_url_pkey PRIMARY KEY (id);
+ALTER TABLE label ADD CONSTRAINT label_pkey PRIMARY KEY (id);
+ALTER TABLE label_meta ADD CONSTRAINT label_meta_pkey PRIMARY KEY(id);
+ALTER TABLE labelalias ADD CONSTRAINT labelalias_pkey PRIMARY KEY (id);
+ALTER TABLE label_tag ADD CONSTRAINT label_tag_pkey PRIMARY KEY (label, tag);
+ALTER TABLE labelwords ADD CONSTRAINT labelwords_pkey PRIMARY KEY (wordid, labelid);
+ALTER TABLE language ADD CONSTRAINT language_pkey PRIMARY KEY (id);
+ALTER TABLE link_attribute ADD CONSTRAINT link_attribute_pkey PRIMARY KEY (id);
+ALTER TABLE link_attribute_type ADD CONSTRAINT link_attribute_type_pkey PRIMARY KEY (id);
+ALTER TABLE lt_album_album ADD CONSTRAINT lt_album_album_pkey PRIMARY KEY (id);
+ALTER TABLE lt_album_artist ADD CONSTRAINT lt_album_artist_pkey PRIMARY KEY (id);
+ALTER TABLE lt_album_label ADD CONSTRAINT lt_album_label_pkey PRIMARY KEY (id);
+ALTER TABLE lt_album_track ADD CONSTRAINT lt_album_track_pkey PRIMARY KEY (id);
+ALTER TABLE lt_album_url ADD CONSTRAINT lt_album_url_pkey PRIMARY KEY (id);
+ALTER TABLE lt_artist_artist ADD CONSTRAINT lt_artist_artist_pkey PRIMARY KEY (id);
+ALTER TABLE lt_artist_label ADD CONSTRAINT lt_artist_label_pkey PRIMARY KEY (id);
+ALTER TABLE lt_artist_track ADD CONSTRAINT lt_artist_track_pkey PRIMARY KEY (id);
+ALTER TABLE lt_artist_url ADD CONSTRAINT lt_artist_url_pkey PRIMARY KEY (id);
+ALTER TABLE lt_label_label ADD CONSTRAINT lt_label_label_pkey PRIMARY KEY (id);
+ALTER TABLE lt_label_track ADD CONSTRAINT lt_label_track_pkey PRIMARY KEY (id);
+ALTER TABLE lt_label_url ADD CONSTRAINT lt_label_url_pkey PRIMARY KEY (id);
+ALTER TABLE lt_track_track ADD CONSTRAINT lt_track_track_pkey PRIMARY KEY (id);
+ALTER TABLE lt_track_url ADD CONSTRAINT lt_track_url_pkey PRIMARY KEY (id);
+ALTER TABLE lt_url_url ADD CONSTRAINT lt_url_url_pkey PRIMARY KEY (id);
+ALTER TABLE moderation_closed ADD CONSTRAINT moderation_closed_pkey PRIMARY KEY (id);
+ALTER TABLE moderation_note_closed ADD CONSTRAINT moderation_note_closed_pkey PRIMARY KEY (id);
+ALTER TABLE moderation_note_open ADD CONSTRAINT moderation_note_open_pkey PRIMARY KEY (id);
+ALTER TABLE moderation_open ADD CONSTRAINT moderation_open_pkey PRIMARY KEY (id);
+ALTER TABLE moderator ADD CONSTRAINT moderator_pkey PRIMARY KEY (id);
+ALTER TABLE moderator_preference ADD CONSTRAINT moderator_preference_pkey PRIMARY KEY (id);
+ALTER TABLE moderator_subscribe_artist ADD CONSTRAINT moderator_subscribe_artist_pkey PRIMARY KEY (id);
+ALTER TABLE moderator_subscribe_label ADD CONSTRAINT moderator_subscribe_label_pkey PRIMARY KEY (id);
+ALTER TABLE editor_subscribe_editor ADD CONSTRAINT editor_subscribe_editor_pkey PRIMARY KEY (id);
+ALTER TABLE "Pending" ADD CONSTRAINT "Pending_pkey" PRIMARY KEY ("SeqId");
+ALTER TABLE "PendingData" ADD CONSTRAINT "PendingData_pkey" PRIMARY KEY ("SeqId", "IsKey");
+ALTER TABLE puid ADD CONSTRAINT puid_pkey PRIMARY KEY (id);
+ALTER TABLE puid_stat ADD CONSTRAINT puid_stat_pkey PRIMARY KEY (id);
+ALTER TABLE puidjoin ADD CONSTRAINT puidjoin_pkey PRIMARY KEY (id);
+ALTER TABLE puidjoin_stat ADD CONSTRAINT puidjoin_stat_pkey PRIMARY KEY (id);
+ALTER TABLE release ADD CONSTRAINT release_pkey PRIMARY KEY (id);
+ALTER TABLE release_group ADD CONSTRAINT release_group_pkey PRIMARY KEY (id);
+ALTER TABLE release_group_meta ADD CONSTRAINT release_group_meta_pkey PRIMARY KEY (id);
+ALTER TABLE release_groupwords ADD CONSTRAINT release_groupwords_pkey PRIMARY KEY (wordid, release_groupid);
+ALTER TABLE release_tag ADD CONSTRAINT release_tag_pkey PRIMARY KEY (release, tag);
+ALTER TABLE replication_control ADD CONSTRAINT replication_control_pkey PRIMARY KEY (id);
+ALTER TABLE script ADD CONSTRAINT script_pkey PRIMARY KEY (id);
+ALTER TABLE script_language ADD CONSTRAINT script_language_pkey PRIMARY KEY (id);
+ALTER TABLE stats ADD CONSTRAINT stats_pkey PRIMARY KEY (id);
+ALTER TABLE tag ADD CONSTRAINT tag_pkey PRIMARY KEY (id);
+ALTER TABLE tag_relation ADD CONSTRAINT tag_relation_pkey PRIMARY KEY (tag1, tag2);
+ALTER TABLE track ADD CONSTRAINT track_pkey PRIMARY KEY (id);
+ALTER TABLE track_meta ADD CONSTRAINT track_meta_pkey PRIMARY KEY(id);
+ALTER TABLE track_tag ADD CONSTRAINT track_tag_pkey PRIMARY KEY (track, tag);
+ALTER TABLE trackwords ADD CONSTRAINT trackwords_pkey PRIMARY KEY (wordid, trackid);
+ALTER TABLE url ADD CONSTRAINT url_pkey PRIMARY KEY (id);
+ALTER TABLE vote_closed ADD CONSTRAINT vote_closed_pkey PRIMARY KEY (id);
+ALTER TABLE vote_open ADD CONSTRAINT vote_open_pkey PRIMARY KEY (id);
+ALTER TABLE wordlist ADD CONSTRAINT wordlist_pkey PRIMARY KEY (id);
+
+-- vi: set ts=4 sw=4 et :
325 sql/CreateReplicationTriggers.sql
@@ -0,0 +1,325 @@
+-- Adjust this setting to control where the objects get created.
+SET search_path = public;
+
+\set ON_ERROR_STOP 1
+
+BEGIN;
+
+CREATE TRIGGER "reptg_album"
+AFTER INSERT OR DELETE OR UPDATE ON "album"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_album_amazon_asin"
+AFTER INSERT OR DELETE OR UPDATE ON "album_amazon_asin"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_album_cdtoc"
+AFTER INSERT OR DELETE OR UPDATE ON "album_cdtoc"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_albumjoin"
+AFTER INSERT OR DELETE OR UPDATE ON "albumjoin"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_albummeta"
+AFTER INSERT OR DELETE OR UPDATE ON "albummeta"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_albumwords"
+AFTER INSERT OR DELETE OR UPDATE ON "albumwords"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_annotation"
+AFTER INSERT OR DELETE OR UPDATE ON "annotation"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artist"
+AFTER INSERT OR DELETE OR UPDATE ON "artist"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artist_meta"
+AFTER INSERT OR DELETE OR UPDATE ON "artist_meta"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artist_relation"
+AFTER INSERT OR DELETE OR UPDATE ON "artist_relation"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artistalias"
+AFTER INSERT OR DELETE OR UPDATE ON "artistalias"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artist_tag"
+AFTER INSERT OR DELETE OR UPDATE ON "artist_tag"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_artistwords"
+AFTER INSERT OR DELETE OR UPDATE ON "artistwords"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+-- Not replicated: automod_election, automod_election_vote
+
+CREATE TRIGGER "reptg_cdtoc"
+AFTER INSERT OR DELETE OR UPDATE ON "cdtoc"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_clientversion"
+AFTER INSERT OR DELETE OR UPDATE ON "clientversion"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_country"
+AFTER INSERT OR DELETE OR UPDATE ON "country"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_currentstat"
+AFTER INSERT OR DELETE OR UPDATE ON "currentstat"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_isrc"
+AFTER INSERT OR DELETE OR UPDATE ON "isrc"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_historicalstat"
+AFTER INSERT OR DELETE OR UPDATE ON "historicalstat"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_label"
+AFTER INSERT OR DELETE OR UPDATE ON "label"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_label_meta"
+AFTER INSERT OR DELETE OR UPDATE ON "label_meta"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_labelalias"
+AFTER INSERT OR DELETE OR UPDATE ON "labelalias"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_label_tag"
+AFTER INSERT OR DELETE OR UPDATE ON "label_tag"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_labelwords"
+AFTER INSERT OR DELETE OR UPDATE ON "labelwords"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_l_album_album"
+AFTER INSERT OR DELETE OR UPDATE ON "l_album_album"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_l_album_artist"
+AFTER INSERT OR DELETE OR UPDATE ON "l_album_artist"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_l_album_label"
+AFTER INSERT OR DELETE OR UPDATE ON "l_album_label"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange" ();
+
+CREATE TRIGGER "reptg_l_album_track"
+AFTER INSERT OR DELETE OR UPDATE ON "l_album_track"
+FOR EACH ROW EXECUTE PROCEDURE "recordchange