108 lines
		
	
	
		
			2.1 KiB
		
	
	
	
		
			MySQL
		
	
	
	
	
	
		
		
			
		
	
	
			108 lines
		
	
	
		
			2.1 KiB
		
	
	
	
		
			MySQL
		
	
	
	
	
	
|   | --
 | ||
|  | -- Set up a many-to-many relationship between tables hosts and eps
 | ||
|  | -- -----------------------------------------------------------------------------
 | ||
|  | --
 | ||
|  | 
 | ||
|  | --
 | ||
|  | -- Make a table called 'new_hosts' containing a copy of the hosts table
 | ||
|  | -- with the same structure but no data. Shrink the hostid column to int(5).
 | ||
|  | --
 | ||
|  | DROP TABLE IF EXISTS new_hosts;
 | ||
|  | CREATE TABLE IF NOT EXISTS new_hosts (
 | ||
|  |     hostid int(5) NOT NULL AUTO_INCREMENT,
 | ||
|  |     PRIMARY KEY (hostid)
 | ||
|  | ) ENGINE=InnoDB
 | ||
|  |     SELECT * FROM hosts WHERE 0 = 1;
 | ||
|  | 
 | ||
|  | -- without the "double host" entries (host='Host1 and Host2')
 | ||
|  | --    SELECT * FROM hosts where host NOT LIKE '% and %';
 | ||
|  | 
 | ||
|  | SHOW warnings;
 | ||
|  | 
 | ||
|  | --
 | ||
|  | -- Make a table called 'new_eps' containing a copy of the eps table without
 | ||
|  | -- the host-related columns but no data.
 | ||
|  | --
 | ||
|  | DROP TABLE IF EXISTS new_eps;
 | ||
|  | CREATE TABLE IF NOT EXISTS new_eps (
 | ||
|  |     id int(5) NOT NULL,
 | ||
|  |     PRIMARY KEY (id)
 | ||
|  | ) ENGINE=InnoDB
 | ||
|  |     SELECT
 | ||
|  | 	id,
 | ||
|  | 	date,
 | ||
|  | 	title,
 | ||
|  | 	summary,
 | ||
|  | 	notes,
 | ||
|  | 	series,
 | ||
|  | 	explicit,
 | ||
|  | 	license,
 | ||
|  | 	tags,
 | ||
|  | 	version,
 | ||
|  | 	valid
 | ||
|  |     FROM eps WHERE 0 = 1;
 | ||
|  | 
 | ||
|  | SHOW warnings;
 | ||
|  | 
 | ||
|  | --
 | ||
|  | -- Table structure for the mapping table 'hosts_eps'
 | ||
|  | --
 | ||
|  | DROP TABLE IF EXISTS hosts_eps;
 | ||
|  | CREATE TABLE IF NOT EXISTS hosts_eps (
 | ||
|  |     host_id int(5) NOT NULL
 | ||
|  | 	REFERENCES new_hosts(hostid),
 | ||
|  |     eps_id int(5) NOT NULL
 | ||
|  | 	REFERENCES new_eps(id),
 | ||
|  |     PRIMARY KEY hosts_eps_pk (host_id,eps_id)
 | ||
|  | ) ENGINE=InnoDB;
 | ||
|  | 
 | ||
|  | SHOW warnings;
 | ||
|  | 
 | ||
|  | --
 | ||
|  | -- Populate the hosts_eps table
 | ||
|  | --
 | ||
|  | /*
 | ||
|  | INSERT INTO hosts_eps (host_id, eps_id)
 | ||
|  |     SELECT ho.hostid, eps.id
 | ||
|  | 	FROM hosts ho
 | ||
|  | 	JOIN eps ON ho.hostid = eps.hostid
 | ||
|  | 	ORDER BY ho.hostid, eps.id;
 | ||
|  | 
 | ||
|  | SHOW warnings;
 | ||
|  | */
 | ||
|  | 
 | ||
|  | --
 | ||
|  | -- Make a view to simplify access to new_hosts and new_eps
 | ||
|  | --
 | ||
|  | DROP VIEW IF EXISTS hosts_with_eps;
 | ||
|  | CREATE VIEW hosts_with_eps AS
 | ||
|  |     SELECT
 | ||
|  | 	nh.hostid,
 | ||
|  | 	nh.host,
 | ||
|  | 	nh.email,
 | ||
|  | 	nh.profile,
 | ||
|  | 	nh.license AS host_license,
 | ||
|  | 	nh.local_image,
 | ||
|  | 	nh.valid AS host_valid,
 | ||
|  | 	ne.id,
 | ||
|  | 	ne.date,
 | ||
|  | 	ne.title,
 | ||
|  | 	ne.summary,
 | ||
|  | 	ne.notes,
 | ||
|  | 	ne.series,
 | ||
|  | 	ne.explicit,
 | ||
|  | 	ne.license AS eps_license,
 | ||
|  | 	ne.tags,
 | ||
|  | 	ne.version,
 | ||
|  | 	ne.valid AS eps_valid
 | ||
|  |     FROM new_hosts nh
 | ||
|  |     JOIN hosts_eps he ON (nh.hostid = he.host_id)
 | ||
|  |     JOIN new_eps ne ON (he.eps_id = ne.id)
 | ||
|  |     ORDER BY nh.hostid, ne.id;
 | ||
|  | 
 | ||
|  | SHOW warnings;
 | ||
|  | 
 | ||
|  | /*
 | ||
|  | vim: syntax=sql ai tw=75:
 | ||
|  | */
 |