Browse files

The Schemaverse v1.0! Changes to Stats and Trophies

  • Loading branch information...
1 parent d593ca7 commit cc73135563393a7cbcce5440f284897d1c409ddf Abstrct committed Feb 23, 2012
Showing with 2,043 additions and 107 deletions.
  1. +39 −0 CHANGELOG
  2. +8 −25 README
  3. +304 −82 create_schemaverse.sql
  4. +70 −0 stat.pl
  5. +56 −0 trophies/trophy_AverageAttackVSDamageRatio.sql
  6. +51 −0 trophies/trophy_AverageDamageDone.sql
  7. +51 −0 trophies/trophy_AverageDistanceCovered.sql
  8. +54 −0 trophies/trophy_AverageFleetSize.sql
  9. +51 −0 trophies/trophy_AverageFuelMined.sql
  10. +56 −0 trophies/trophy_AveragePlanetsMaintained.sql
  11. +56 −0 trophies/trophy_BelowAverageAttackVSDamageRatio.sql
  12. +51 −0 trophies/trophy_BelowAverageDamageDone.sql
  13. +51 −0 trophies/trophy_BelowAverageDistanceCovered.sql
  14. +54 −0 trophies/trophy_BelowAverageFleetSize.sql
  15. +51 −0 trophies/trophy_BelowAverageFuelMined.sql
  16. +51 −0 trophies/trophy_BelowAverageUpgrades.sql
  17. +59 −0 trophies/trophy_FinalStandings_1st.sql
  18. +68 −0 trophies/trophy_FirstBlood.sql
  19. +57 −0 trophies/trophy_LeastConqueredPlanets.sql
  20. +57 −0 trophies/trophy_LeastDamageDone.sql
  21. +57 −0 trophies/trophy_LeastDistanceCovered.sql
  22. +57 −0 trophies/trophy_LeastFuelMined.sql
  23. +57 −0 trophies/trophy_LeastShips.sql
  24. +57 −0 trophies/trophy_MostConqueredPlanets.sql
  25. +57 −0 trophies/trophy_MostDamageDone.sql
  26. +57 −0 trophies/trophy_MostDamageTaken.sql
  27. +57 −0 trophies/trophy_MostDistanceCovered.sql
  28. +57 −0 trophies/trophy_MostFuelMined.sql
  29. +57 −0 trophies/trophy_MostPlanetsLost.sql
  30. +57 −0 trophies/trophy_MostPowerfulShips.sql
  31. +57 −0 trophies/trophy_MostShips.sql
  32. +57 −0 trophies/trophy_MostShipsDestroyed.sql
  33. +64 −0 trophies/trophy_Participation.sql
View
39 CHANGELOG
@@ -1,3 +1,42 @@
+# 2012 02 23
+
+create_schemaverse.sql - v1.0.0 <--- Awwwwww yeah. That's nice.
+stat.pl - v1.0
+
+Gameplay / System Changes
+[Trophies]
+- Trophies now have a Weight and Run Order
+- Trophies can now be back-run for older rounds
+- ROUND_CONTROL() calls the new trophy_script_#(_round_id integer) instead of trophy_script_#()
+- 29 New trophies were created to take advantage of the Weighting
+- You can see who is currently in the running for a trophy by issuing a select against trophy_script_#((SELECT last_value FROM round_seq)); where the # is the trophy ID.
+
+[Stats]
+- Stat Tables: player_overall_stats, player_round_stats, round_stats
+- Stat Views: current_player_stats, current_round_stats, player_stats
+- player_round_stats are updated 1 by 1 over time in stat.pl
+- round_stats is updated after every 100 player updates in stat.pl
+- player_stats shows both stats for the current round as well as aggregated stats from previous rounds
+- players have access to SELECT on all stat views and tables. The table results will not be as fresh but will be returned much faster compared to the views
+- ROUND_CONTROL() updates the stats before issuing trophies
+- ROUND_CONTROL() prepares the new stat rows for the new round in player_round_stats and round_stats
+
+[Misc]
+Changed where the Variable related functions were created within create_schemaverse.sql so that the script actually works
+
+# 2012 01 23
+
+Bug Fix
+- ships_in_range.health now returns a numeric value rather than an integer. Represents the percentage of a ship's remaining health.
+
+# 2012 01 15
+
+
+Gameplay change / Bug Fix
+- Ships can no longer create ships at location (0,0). This was how the rule was intended during the recent map changes but I missed commenting out a line in create_ship
+- A ship's first coordinates are also now added to the ship_flight_recorder during create_ship_event
+
+
# 2012 01 13
create_schemaverse.sql - v0.14.2
View
33 README
@@ -1,39 +1,22 @@
What is Schemaverse?
-The Schemaverse is a space-based strategy game implemented entirely within a PostgreSQL database.
-Compete against other players using raw SQL commands to command your fleet. Or, if your
-PL/pgSQL-foo is strong, wield it to write AI and have your fleet command itself!
+The Schemaverse is a space-based strategy game implemented entirely within a PostgreSQL database. Compete against other players using raw SQL commands to command your fleet. Or, if your PL/pgSQL-foo is strong, wield it to write AI and have your fleet command itself!
Why?
-Originally, I just wanted to see if I could actually pull it off. Now that I know I can,
-I am developing the game further to make it actually fun and challenging to compete within.
+Originally, I just wanted to see if I could actually pull it off. Now that I know I can, I am developing the game further to make it actually fun and challenging to compete within.
-Quite a bit of effort will also be put into making this project fit to be used as a teaching
-aid for all levels of database lessons. If you would like to help with this please contact me :)
+Quite a bit of effort will also be put into making this project fit to be used as a teaching aid for all levels of database lessons. If you would like to help with this please contact me :)
-Schemaverse was tested on Postgres 9.0. For the most, the game is working but I am
-still testing some functions. I have put it online so that others can help me test it
-more thoroughly.
+Schemaverse was tested on Postgres 9.1. For the most, the game is working but I am still testing some functions. I have put it online so that others can help me test it more thoroughly.
-Yes, a lot of my queries are a bit ugly at this point. Optimization will come after
-the game is working.
+Yes, a lot of my queries are a bit ugly at this point. Optimization is now being tackled.
IMPORTANT NOTES
-I created this game to learn more about security in postgres. This means that this game,
-in it's beta state, is probably extremely insecure. DON'T RUN THIS ON SOMETHING IMPORTANT.
+I created this game to learn more about security in postgres. This means that this game is probably extremely insecure.
-I really suggest you create a user named schemaverse which should have most rights over
-the schemaverse database. If you choose to use a different username you will need to
-change some spots of the create script which reference this user.
-
-Each player has their own postgres user account. Keep this in mind so you don't
-accidently allow a user to take over high privileged accounts.
-
-The create script will also create a group called players automatically. Obviously, if you
-already have a user named this in your installation this will cuase problems.
-
-Once the game hits a stable release I will write a script to allow for more custom installations.
+DON'T RUN THIS ON SOMETHING IMPORTANT.
-Abstrct
+www.schemaverse.com
View
386 create_schemaverse.sql
@@ -1,7 +1,7 @@
-- Schemaverse
-- Created by Josh McDougall
--- v0.14.2 - Now I remember where I put that ship
-
+-- v1.0.0 - The Birthdaayyy Release
+
create language 'plpgsql';
CREATE SEQUENCE round_seq
@@ -29,7 +29,6 @@ CREATE TABLE variable
CONSTRAINT pk_variable PRIMARY KEY (name, player_id)
);
-CREATE VIEW public_variable AS SELECT * FROM variable WHERE (private='f' AND player_id=0) OR player_id=GET_PLAYER_ID(SESSION_USER);
INSERT INTO variable VALUES
@@ -41,63 +40,21 @@ INSERT INTO variable VALUES
('MAX_SHIP_FUEL','f',16000,'','This is the maximum fuel a ship can have'::TEXT,0),
('MAX_SHIP_SPEED','f',5000,'','This is the maximum speed a ship can travel'::TEXT,0),
('MAX_SHIP_HEALTH','f',1000,'','This is the maximum health a ship can have'::TEXT,0),
- ('ROUND_START_DATE','f',0,'2011-04-17','The day the round started.'::TEXT,0),
+ ('ROUND_START_DATE','f',0,'1986-03-27','The day the round started.'::TEXT,0),
('ROUND_LENGTH','f',0,'7 days','The length of time a round takes to complete'::TEXT,0),
('DEFENSE_EFFICIENCY', 'f', 50, '', 'Used to calculate attack with defense'::TEXT,0);
-CREATE OR REPLACE FUNCTION GET_NUMERIC_VARIABLE(variable_name character varying) RETURNS integer AS $get_numeric_variable$
-DECLARE
- value integer;
-BEGIN
- IF CURRENT_USER = 'schemaverse' THEN
- SELECT numeric_value INTO value FROM variable WHERE name = variable_name and player_id=0;
- ELSE
- SELECT numeric_value INTO value FROM public_variable WHERE name = variable_name;
- END IF;
- RETURN value;
-END $get_numeric_variable$ LANGUAGE plpgsql;
-
-CREATE OR REPLACE FUNCTION GET_CHAR_VARIABLE(variable_name character varying) RETURNS character varying AS $get_char_variable$
+CREATE OR REPLACE FUNCTION GET_DISTANCE(loc_x_1 integer, loc_y_1 integer, loc_x_2 integer, loc_y_2 integer )
+ RETURNS integer AS
+$get_distance$
DECLARE
- value character varying;
BEGIN
- IF CURRENT_USER = 'schemaverse' THEN
- SELECT char_value INTO value FROM variable WHERE name = variable_name and player_id=0;
- ELSE
- SELECT char_value INTO value FROM public_variable WHERE name = variable_name;
- END IF;
- RETURN value;
-END $get_char_variable$ LANGUAGE plpgsql;
-
-CREATE OR REPLACE FUNCTION SET_NUMERIC_VARIABLE(variable_name character varying, new_value integer) RETURNS integer AS $set_numeric_variable$
-BEGIN
- IF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER)) = 1 THEN
- UPDATE variable SET numeric_value=new_value WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER);
- ELSEIF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=0) = 1 THEN
- EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''Cannot update a system variable'';';
- ELSE
- INSERT INTO variable VALUES(variable_name,'f',new_value,'','',GET_PLAYER_ID(SESSION_USER));
- END IF;
- RETURN new_value;
-END $set_numeric_variable$ SECURITY definer LANGUAGE plpgsql ;
-
-CREATE OR REPLACE FUNCTION SET_CHAR_VARIABLE(variable_name character varying, new_value character varying) RETURNS character varying AS
-$set_char_variable$
-BEGIN
- IF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER)) = 1 THEN
- UPDATE variable SET char_value=new_value WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER);
- ELSEIF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=0) = 1 THEN
- EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''Cannot update a system variable'';';
- ELSE
- INSERT INTO variable VALUES(variable_name,'f',0,new_value,'',GET_PLAYER_ID(SESSION_USER));
- END IF;
- RETURN new_value;
-END $set_char_variable$ SECURITY definer LANGUAGE plpgsql;
-
-
+ RETURN sqrt(((loc_x_1-loc_x_2)^2)+((loc_y_1-loc_y_2)^2))::integer;
+END $get_distance$
+ LANGUAGE plpgsql;
CREATE TABLE price_list
@@ -159,6 +116,60 @@ CREATE VIEW my_player AS
ALTER TABLE variable ADD CONSTRAINT fk_variable_player_id FOREIGN KEY (player_id)
REFERENCES player (id) MATCH SIMPLE;
+CREATE VIEW public_variable AS SELECT * FROM variable WHERE (private='f' AND player_id=0) OR player_id=GET_PLAYER_ID(SESSION_USER);
+
+
+CREATE OR REPLACE FUNCTION GET_NUMERIC_VARIABLE(variable_name character varying) RETURNS integer AS $get_numeric_variable$
+DECLARE
+ value integer;
+BEGIN
+ IF CURRENT_USER = 'schemaverse' THEN
+ SELECT numeric_value INTO value FROM variable WHERE name = variable_name and player_id=0;
+ ELSE
+ SELECT numeric_value INTO value FROM public_variable WHERE name = variable_name;
+ END IF;
+ RETURN value;
+END $get_numeric_variable$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION GET_CHAR_VARIABLE(variable_name character varying) RETURNS character varying AS $get_char_variable$
+DECLARE
+ value character varying;
+BEGIN
+ IF CURRENT_USER = 'schemaverse' THEN
+ SELECT char_value INTO value FROM variable WHERE name = variable_name and player_id=0;
+ ELSE
+ SELECT char_value INTO value FROM public_variable WHERE name = variable_name;
+ END IF;
+ RETURN value;
+END $get_char_variable$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION SET_NUMERIC_VARIABLE(variable_name character varying, new_value integer) RETURNS integer AS $set_numeric_variable$
+BEGIN
+ IF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER)) = 1 THEN
+ UPDATE variable SET numeric_value=new_value WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER);
+ ELSEIF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=0) = 1 THEN
+ EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''Cannot update a system variable'';';
+ ELSE
+ INSERT INTO variable VALUES(variable_name,'f',new_value,'','',GET_PLAYER_ID(SESSION_USER));
+ END IF;
+ RETURN new_value;
+END $set_numeric_variable$ SECURITY definer LANGUAGE plpgsql ;
+
+CREATE OR REPLACE FUNCTION SET_CHAR_VARIABLE(variable_name character varying, new_value character varying) RETURNS character varying AS
+$set_char_variable$
+BEGIN
+ IF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER)) = 1 THEN
+ UPDATE variable SET char_value=new_value WHERE name=variable_name AND player_id=GET_PLAYER_ID(SESSION_USER);
+ ELSEIF (SELECT count(*) FROM variable WHERE name=variable_name AND player_id=0) = 1 THEN
+ EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''Cannot update a system variable'';';
+ ELSE
+ INSERT INTO variable VALUES(variable_name,'f',0,new_value,'',GET_PLAYER_ID(SESSION_USER));
+ END IF;
+ RETURN new_value;
+END $set_char_variable$ SECURITY definer LANGUAGE plpgsql;
+
+
+
CREATE RULE public_variable_update AS ON UPDATE to public_variable
DO INSTEAD UPDATE variable
SET
@@ -478,7 +489,7 @@ SELECT
players.id as ship_in_range_of,
enemies.player_id as player_id,
enemies.name as name,
- enemies.current_health/enemies.max_health as health,
+ ((enemies.current_health)::numeric/(enemies.max_health)::numeric)::numeric as health,
--enemies.current_health as current_health,
--enemies.max_health as max_health,
--enemies.current_fuel as current_fuel,
@@ -592,7 +603,7 @@ BEGIN
IF
--(NOT (NEW.location_x between -3000 and 3000 AND NEW.location_y between -3000 and 3000)) AND
- (NOT (NEW.location_x = 0 AND NEW.location_y = 0)) AND
+-- (NOT (NEW.location_x = 0 AND NEW.location_y = 0)) AND
(SELECT COUNT(id) FROM planets WHERE NEW.location_x=location_x AND NEW.location_y=location_y AND conqueror_id=NEW.player_id) = 0 THEN
EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''When creating a new ship, the coordinates must each be between -3000 and 3000 OR be the same as a planet where your player currently holds the conqueror position'';';
RETURN NULL;
@@ -603,7 +614,8 @@ BEGIN
EXECUTE 'NOTIFY ' || get_player_error_channel() ||', ''Not enough funds to purchase ship'';';
RETURN NULL;
END IF;
-
+
+
RETURN NEW;
END
$create_ship$ LANGUAGE plpgsql;
@@ -613,6 +625,9 @@ CREATE TRIGGER CREATE_SHIP BEFORE INSERT ON ship
CREATE OR REPLACE FUNCTION CREATE_SHIP_EVENT() RETURNS trigger AS $create_ship_event$
BEGIN
+
+ INSERT INTO ship_flight_recorder VALUES(NEW.id, (SELECT last_value FROM tic_seq)-1, NEW.location_x, NEW.location_y);
+
INSERT INTO event(action, player_id_1, ship_id_1, location_x, location_y, public, tic)
VALUES('BUY_SHIP',NEW.player_id, NEW.id, NEW.location_x, NEW.location_y, 'f',(SELECT last_value FROM tic_seq));
RETURN NULL;
@@ -1640,7 +1655,9 @@ create table trophy (
script_declarations text,
creator integer NOT NULL REFERENCES player(id),
approved boolean default 'f',
- round_started integer
+ round_started integer,
+ weight smallint,
+ run_order smallint
);
CREATE SEQUENCE trophy_id_seq
@@ -1685,11 +1702,11 @@ BEGIN
END IF;
secret := 'trophy_script_' || (RANDOM()*1000000)::integer;
- EXECUTE 'CREATE OR REPLACE FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'() RETURNS SETOF trophy_winner AS $'||secret||'$
+ EXECUTE 'CREATE OR REPLACE FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'(_round_id integer) RETURNS SETOF trophy_winner AS $'||secret||'$
DECLARE
this_trophy_id integer;
- this_round integer;
- winner trophy_winner%rowtype;
+ this_round integer; -- Deprecated, use _round_id in your script instead
+ winner trophy_winner%rowtype;
' || NEW.script_declarations || '
BEGIN
this_trophy_id := '|| NEW.id||';
@@ -1698,9 +1715,9 @@ BEGIN
RETURN;
END $'||secret||'$ LANGUAGE plpgsql;'::TEXT;
- EXECUTE 'REVOKE ALL ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'() FROM PUBLIC'::TEXT;
- EXECUTE 'REVOKE ALL ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'() FROM players'::TEXT;
- EXECUTE 'GRANT EXECUTE ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'() TO schemaverse'::TEXT;
+ EXECUTE 'REVOKE ALL ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'(integer) FROM PUBLIC'::TEXT;
+ EXECUTE 'REVOKE ALL ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'(integer) FROM players'::TEXT;
+ EXECUTE 'GRANT EXECUTE ON FUNCTION TROPHY_SCRIPT_'|| NEW.id ||'(integer) TO schemaverse'::TEXT;
END IF;
ELSEIF NOT player_id = OLD.creator THEN
RETURN OLD;
@@ -2144,7 +2161,8 @@ BEGIN
UPDATE planet SET fuel = (fuel - mined_player_fuel)::integer WHERE id = current_planet_id;
INSERT INTO event(action, player_id_1,ship_id_1, referencing_id, descriptor_numeric, location_x,location_y, public, tic)
- VALUES('MINE_SUCCESS',miners.player_id, miners.ship_id, miners.planet_id , mined_player_fuel,miners.location_x,miners.location_y,'t',(SELECT last_value FROM tic_seq));
+ VALUES('MINE_SUCCESS',miners.player_id, miners.ship_id, miners.planet_id , mined_player_fuel,miners.location_x,miners.location_y,'t',
+ (SELECT last_value FROM tic_seq));
END IF;
limit_counter = limit_counter + 1;
ELSE
@@ -2403,21 +2421,164 @@ select
ceil((select avg(balance) from player where id!=0)) as avg_balance
from player ;
-CREATE OR REPLACE VIEW current_player_stats AS
-select
- player.id as player_id,
- player.username as username,
- (CASE WHEN (select count(id) from online_players where online_players.id=player.id) = 1 THEN true ELSE false END) as online,
- (SELECT count(id) from ship where player_id=player.id and destroyed='f') as alive_ships,
- (SELECT count(id) from ship where player_id=player.id and destroyed='t') as destroyed_ships,
- (select count(id) from trade where player.id in (player_id_1, player_id_2) ) as total_trades,
- (select count(id) from trade where player_id_1!=confirmation_1 OR player_id_2!=confirmation_2) as active_trades,
- player.fuel_reserve as fuel_reserves,
- player.balance as currency_balance,
- (SELECT count(id) from planet WHERE conqueror_id=player.id) as conquered_planets
-from player;
-
-
+CREATE OR REPLACE VIEW current_player_stats AS
+ SELECT
+ player.id AS player_id,
+ player.username,
+ COALESCE(against_player.damage_taken,0) AS damage_taken,
+ COALESCE(for_player.damage_done,0) AS damage_done,
+ COALESCE(for_player.planets_conquered,0) AS planets_conquered,
+ COALESCE(against_player.planets_lost,0) AS planets_lost,
+ COALESCE(for_player.ships_built,0) AS ships_built,
+ COALESCE(for_player.ships_lost,0) AS ships_lost,
+ COALESCE(for_player.ship_upgrades,0) AS ship_upgrades,
+ COALESCE(((
+ SELECT sum(get_distance(r.location_x, r.location_y, r2.location_x, r2.location_y)::bigint)::bigint AS sum
+ FROM ship_flight_recorder r, ship_flight_recorder r2, ship s
+ WHERE s.player_id = player.id AND r.ship_id = s.id AND r2.ship_id = r.ship_id AND r2.tic = (r.tic + 1)))::numeric, 0::numeric) AS distance_travelled,
+ COALESCE(for_player.fuel_mined,0) AS fuel_mined
+ FROM player
+
+ LEFT OUTER JOIN (SELECT
+ SUM(CASE WHEN event.action ='ATTACK' THEN event.descriptor_numeric ELSE NULL END ) as damage_done,
+ COUNT(CASE WHEN event.action ='CONQUER' THEN COALESCE(event.descriptor_numeric,0) ELSE NULL END ) as planets_conquered,
+ COUNT(CASE WHEN event.action ='BUY_SHIP' THEN COALESCE(event.descriptor_numeric,0) ELSE NULL END ) as ships_built,
+ COUNT(CASE WHEN event.action ='EXPLODE' THEN COALESCE(event.descriptor_numeric,0) ELSE NULL END ) as ships_lost,
+ SUM(CASE WHEN event.action ='UPGRADE_SHIP' THEN event.descriptor_numeric ELSE NULL END ) as ship_upgrades,
+ SUM(CASE WHEN event.action ='MINE_SUCCESS' THEN event.descriptor_numeric ELSE NULL END ) as fuel_mined,
+ event.player_id_1
+ FROM event event
+ WHERE event.action in ('ATTACK','CONQUER','BUY_SHIP','EXPLODE','UPGRADE_SHIP','MINE_SUCCESS')
+ GROUP BY player_id_1)
+ for_player ON (for_player.player_id_1=player.id)
+
+ LEFT OUTER JOIN (SELECT
+ SUM(CASE WHEN event.action = 'ATTACK' THEN event.descriptor_numeric ELSE NULL END) AS damage_taken,
+ COUNT(CASE WHEN event.action = 'CONQUER' THEN COALESCE(event.descriptor_numeric,0) ELSE NULL END) as planets_lost,
+ event.player_id_2
+ FROM event event
+ WHERE event.action IN ('ATTACK','CONQUER')
+ GROUP BY player_id_2)
+ against_player ON (against_player.player_id_2=player.id)
+ WHERE id <> 0;
+
+CREATE OR REPLACE VIEW current_round_stats AS SELECT
+ round.round_id,
+ coalesce(avg(CASE WHEN against_player.action='ATTACK' THEN coalesce(against_player.sum,0) ELSE NULL END),0)::integer as avg_damage_taken,
+ coalesce( avg(CASE WHEN for_player.action='ATTACK' THEN coalesce(for_player.sum,0) ELSE NULL END) ,0)::integer as avg_damage_done,
+ coalesce( avg(CASE WHEN for_player.action='CONQUER' THEN coalesce(for_player.count,0) ELSE NULL END),0)::integer as avg_planets_conquered,
+ coalesce(avg(CASE WHEN against_player.action='CONQUER' THEN coalesce(against_player.count,0) ELSE NULL END),0)::integer as avg_planets_lost,
+ coalesce( avg(CASE WHEN for_player.action='BUY_SHIP' THEN coalesce(for_player.count,0) ELSE NULL END),0)::integer as avg_ships_built,
+ coalesce(avg(CASE WHEN for_player.action='EXPLODE' THEN coalesce(for_player.count,0) ELSE NULL END),0)::integer as avg_ships_lost,
+ coalesce( avg(CASE WHEN for_player.action='UPGRADE_SHIP' THEN coalesce(for_player.sum,0) ELSE NULL END),0)::integer as avg_ship_upgrades,
+ coalesce( avg(CASE WHEN for_player.action='MINE_SUCCESS' THEN coalesce(for_player.sum,0) ELSE NULL END),0)::integer as avg_fuel_mined,
+ (SELECT avg(prs.distance_travelled) FROM player_round_stats prs WHERE prs.round_id=round.round_id) as avg_distance_travelled
+ FROM
+ (SELECT last_value as round_id from round_seq) round
+ LEFT OUTER JOIN
+ (SELECT
+ (SELECT last_value as round_id from round_seq) as round_id,
+ action,
+ CASE WHEN event.action IN ('ATTACK','UPGRADE_SHIP','MINE_SUCCESS') THEN sum(coalesce(event.descriptor_numeric,0)) ELSE NULL END AS sum,
+ CASE WHEN event.action IN ('BUY_SHIP','EXPLODE','CONQUER') THEN count(*) ELSE NULL END as count
+ FROM event event
+ WHERE event.action in ('ATTACK','CONQUER','BUY_SHIP','EXPLODE','UPGRADE_SHIP','MINE_SUCCESS')
+ GROUP BY player_id_1, action)
+ for_player ON (for_player.round_id=round.round_id)
+ LEFT OUTER JOIN
+ (SELECT
+ (SELECT last_value as round_id from round_seq) as round_id,
+ action,
+ CASE WHEN event.action = 'ATTACK' THEN sum(coalesce(event.descriptor_numeric,0)) ELSE NULL END AS sum,
+ CASE WHEN event.action IN ('CONQUER') THEN count(*) ELSE NULL END as count
+ FROM event event WHERE event.action IN ('ATTACK','CONQUER')
+ GROUP BY player_id_2, action)
+ against_player ON (against_player.round_id=round.round_id)
+ GROUP BY round.round_id;
+
+CREATE TABLE player_overall_stats
+(
+ player_id integer NOT NULL,
+ damage_taken bigint,
+ damage_done bigint,
+ planets_conquered integer,
+ planets_lost integer,
+ ships_built integer,
+ ships_lost integer,
+ ship_upgrades bigint,
+ distance_travelled bigint,
+ fuel_mined bigint,
+ trophy_score integer,
+ CONSTRAINT pk_player_overall_stats PRIMARY KEY (player_id )
+);
+
+CREATE TABLE player_round_stats
+(
+ player_id integer NOT NULL,
+ round_id integer NOT NULL,
+ damage_taken bigint NOT NULL DEFAULT 0,
+ damage_done bigint NOT NULL DEFAULT 0,
+ planets_conquered smallint NOT NULL DEFAULT 0,
+ planets_lost smallint NOT NULL DEFAULT 0,
+ ships_built smallint NOT NULL DEFAULT 0,
+ ships_lost smallint NOT NULL DEFAULT 0,
+ ship_upgrades integer NOT NULL DEFAULT 0,
+ distance_travelled integer NOT NULL DEFAULT 0,
+ fuel_mined bigint NOT NULL DEFAULT 0,
+ trophy_score smallint NOT NULL DEFAULT 0,
+ last_updated timestamp without time zone NOT NULL DEFAULT now(),
+ CONSTRAINT pk_player_round_stats PRIMARY KEY (player_id , round_id )
+);
+
+CREATE TABLE round_stats
+(
+ round_id integer NOT NULL,
+ first_blood integer,
+ participants integer,
+ avg_damage_done integer,
+ avg_damage_taken integer,
+ avg_ships integer,
+ avg_ships_destroyed integer,
+ avg_planets integer,
+ avg_distance_travelled integer,
+ avg_fuel_mined integer,
+ avg_balance integer,
+ avg_ship_upgrades integer,
+ avg_distance_travelled bigint,
+ CONSTRAINT pk_round_stat PRIMARY KEY (round_id )
+);
+
+CREATE OR REPLACE VIEW player_stats AS
+ SELECT
+ rs.player_id as player_id,
+ GET_PLAYER_USERNAME(rs.player_id) as username,
+ CASE WHEN (( SELECT count(online_players.id) AS count FROM online_players WHERE online_players.id = rs.player_id)) = 1 THEN true ELSE false END AS online,
+ rs.damage_taken as round_damage_taken,
+ coalesce(os.damage_taken,0)+rs.damage_taken as overall_damage_taken,
+ rs.damage_done as round_damage_done,
+ coalesce(os.damage_done,0)+rs.damage_done as overall_damamge_done,
+ rs.planets_conquered as round_planets_conquered,
+ coalesce(os.planets_conquered,0)+rs.planets_conquered as overall_planets_conquered,
+ rs.planets_lost as round_planets_lost,
+ coalesce(os.planets_lost,0)+rs.planets_lost as overall_planets_lost,
+ rs.ships_built as round_ships_built,
+ coalesce(os.ships_built,0)+rs.ships_built as overall_ships_built,
+ rs.ships_lost as round_ships_lost,
+ coalesce(os.ships_lost,0)+rs.ships_lost as overall_ships_lost,
+ rs.ship_upgrades as round_ship_upgrades,
+ coalesce(os.ship_upgrades,0)+rs.ship_upgrades as overall_ship_upgrades,
+ rs.distance_travelled as round_distance_travelled,
+ coalesce(os.distance_travelled,0)+rs.distance_travelled as overall_distance_travelled,
+ rs.fuel_mined as round_fuel_mined,
+ coalesce(os.fuel_mined,0)+rs.fuel_mined as overall_fuel_mined,
+ coalesce(os.trophy_score,0) as overall_trophy_score,
+ rs.last_updated as last_updated
+FROM
+ player_round_stats rs, player_overall_stats os
+WHERE
+ rs.player_id=os.player_id
+ and rs.round_id = (( SELECT round_seq.last_value FROM round_seq));
+
-- Create group 'players' and define the permissions
CREATE GROUP players WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT;
@@ -2499,12 +2660,24 @@ GRANT UPDATE ON my_fleets TO players;
REVOKE ALL ON price_list FROM players;
GRANT SELECT ON price_list TO players;
+
+REVOKE ALL ON round_stats FROM players;
+REVOKE ALL ON player_round_stats FROM players;
+REVOKE ALL ON player_overall_stats FROM players;
+REVOKE ALL ON stat_log FROM players;
REVOKE ALL ON current_stats FROM players;
REVOKE ALL ON current_player_stats FROM players;
-REVOKE ALL ON stat_log FROM players;
+REVOKE ALL ON current_round_stats FROM players;
+REVOKE ALL ON player_stats FROM players;
+GRANT SELECT ON round_stats TO players;
+GRANT SELECT ON player_round_stats TO players;
+GRANT SELECT ON player_overall_stats TO players;
+GRANT SELECT ON stat_log TO players;
GRANT SELECT ON current_stats TO players;
GRANT SELECT ON current_player_stats TO players;
-GRANT SELECT ON stat_log TO players;
+GRANT SELECT ON current_round_stats TO players;
+GRANT SELECT ON player_stats TO players;
+
REVOKE ALL ON action FROM players;
GRANT SELECT ON action TO players;
@@ -2529,6 +2702,7 @@ $round_control$
DECLARE
new_planet record;
trophies RECORD;
+ players RECORD;
p RECORD;
BEGIN
@@ -2540,8 +2714,50 @@ BEGIN
RETURN 'f';
END IF;
- FOR trophies IN SELECT id FROM trophy WHERE approved='t' LOOP
- EXECUTE 'INSERT INTO player_trophy SELECT * FROM trophy_script_' || trophies.id ||'();';
+
+ UPDATE round_stats SET
+ avg_damage_taken = current_round_stats.avg_damage_taken,
+ avg_damage_done = current_round_stats.avg_damage_done,
+ avg_planets_conquered = current_round_stats.avg_planets_conquered,
+ avg_planets_lost = current_round_stats.avg_planets_lost,
+ avg_ships_built = current_round_stats.avg_ships_built,
+ avg_ships_lost = current_round_stats.avg_ships_lost,
+ avg_ship_upgrades =current_round_stats.avg_ship_upgrades,
+ avg_fuel_mined = current_round_stats.avg_fuel_mined
+ FROM current_round_stats
+ WHERE round_stats.round_id=(SELECT last_value FROM round_seq);
+
+ FOR players IN SELECT * FROM player LOOP
+ UPDATE player_round_stats SET
+ damage_taken = current_player_stats.damage_taken,
+ damage_done = current_player_stats.damage_done,
+ planets_conquered = current_player_stats.planets_conquered,
+ planets_lost = current_player_stats.planets_lost,
+ ships_built = current_player_stats.ships_built,
+ ships_lost = current_player_stats.ships_lost,
+ ship_upgrades =current_player_stats.ship_upgrades,
+ fuel_mined = current_player_stats.fuel_mined,
+ last_updated=NOW()
+ FROM current_player_stats
+ WHERE player_round_stats.player_id=players.id AND current_player_stats.player_id=players.id AND player_round_stats.round_id=(select last_value from round_seq);
+
+ UPDATE player_overall_stats SET
+ damage_taken = player_overall_stats.damage_taken + player_round_stats.damage_taken,
+ damage_done = player_overall_stats.damage_done + player_round_stats.damage_done,
+ planets_conquered = player_overall_stats.planets_conquered + player_round_stats.planets_conquered,
+ planets_lost = player_overall_stats.planets_lost + player_round_stats.planets_lost,
+ ships_built = player_overall_stats.ships_built +player_round_stats.ships_built,
+ ships_lost = player_overall_stats.ships_lost + player_round_stats.ships_lost,
+ ship_upgrades = player_overall_stats.ship_upgrades + player_round_stats.ship_upgrades,
+ fuel_mined = player_overall_stats.fuel_mined + player_round_stats.fuel_mined
+ FROM player_round_stats
+ WHERE player_overall_stats.player_id=player_round_stats.player_id
+ and player_overall_stats.player_id=players.id and player_round_stats.round_id=(select last_value from round_seq);
+ END LOOP;
+
+
+ FOR trophies IN SELECT id FROM trophy WHERE approved='t' ORDER by run_order ASC LOOP
+ EXECUTE 'INSERT INTO player_trophy SELECT * FROM trophy_script_' || trophies.id ||'((SELECT last_value FROM round_seq));';
END LOOP;
alter table planet disable trigger all;
@@ -2651,6 +2867,12 @@ BEGIN
UPDATE variable SET char_value='today'::date WHERE name='ROUND_START_DATE';
+
+ FOR players IN SELECT * from player WHERE ID <> 0 LOOP
+ INSERT INTO player_round_stats(player_id, round_id) VALUES (players.id, (select last_value from round_seq));
+ END LOOP;
+ INSERT INTO round_stats(round_id) VALUES((SELECT last_value FROM round_seq));
+
RETURN 't';
END;
$round_control$
View
70 stat.pl
@@ -0,0 +1,70 @@
+
+#!/usr/bin/perl
+#############################
+# Stat v1.0 #
+# Created by Josh McDougall #
+#############################
+# This should be run inside a screen session
+# stat.pl keeps player_round_stats up to date
+
+# use module
+use DBI;
+
+# Config Variables
+my $db_name = "schemaverse";
+my $db_username = "schemaverse";
+
+# Make the master database connection
+my $master_connection = DBI->connect("dbi:Pg:dbname=${db_name};host=localhost", $db_username);
+
+while (1){
+
+
+ my $sql = "SELECT player_id, round_id FROM player_round_stats ORDER BY round_id DESC, last_updated ASC LIMIT 1;";
+
+ my $rs = $master_connection->prepare($sql);
+ $rs->execute();
+ while (($player_id, $round_id) = $rs->fetchrow()) {
+ my $sql = <<SQLSTATEMENT;
+ UPDATE player_round_stats SET
+ damage_taken = current_player_stats.damage_taken,
+ damage_done = current_player_stats.damage_done,
+ planets_conquered = current_player_stats.planets_conquered,
+ planets_lost = current_player_stats.planets_lost,
+ ships_built = current_player_stats.ships_built,
+ ships_lost = current_player_stats.ships_lost,
+ ship_upgrades =current_player_stats.ship_upgrades,
+ fuel_mined = current_player_stats.fuel_mined,
+ distance_travelled = current_player_stats.distance_travelled,
+ last_updated=NOW()
+ FROM current_player_stats
+ WHERE player_round_stats.player_id=current_player_stats.player_id
+ AND current_player_stats.player_id=${player_id} AND player_round_stats.round_id=${round_id};
+
+SQLSTATEMENT
+ $master_connection->do($sql);
+
+ if ($player_id % 100 == 0) {
+ $sql = <<SQLSTATEMENT;
+ UPDATE round_stats SET
+ avg_damage_taken = current_round_stats.avg_damage_taken,
+ avg_damage_done = current_round_stats.avg_damage_done,
+ avg_planets_conquered = current_round_stats.avg_planets_conquered,
+ avg_planets_lost = current_round_stats.avg_planets_lost,
+ avg_ships_built = current_round_stats.avg_ships_built,
+ avg_ships_lost = current_round_stats.avg_ships_lost,
+ avg_ship_upgrades =current_round_stats.avg_ship_upgrades,
+ avg_fuel_mined = current_round_stats.avg_fuel_mined,
+ avg_distance_travelled = current_round_stats.avg_distance_travelled
+ FROM current_round_stats
+ WHERE round_stats.round_id=${round_id};
+
+SQLSTATEMENT
+ $master_connection->do($sql);
+ }
+ }
+ $rs->finish;
+
+ #sleep(5);
+}
+$master_connection->disconnect();
View
56 trophies/trophy_AverageAttackVSDamageRatio.sql
@@ -0,0 +1,56 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Higher Attack/Damage ratio than average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Honourable Combat Performance' ,
+
+-- Trophy Description
+'The players Attack done VS Damage Taken ratio is greater than the average'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player.id as player_id
+ FROM
+ player,
+ (SELECT player_round_stats.player_id,
+ CASE WHEN player_round_stats.damage_taken = 0 THEN player_round_stats.damage_done
+ ELSE (player_round_stats.damage_done / player_round_stats.damage_taken) END as player_damage
+ FROM player_round_stats WHERE player_round_stats.round_id = _round_id) prs,
+ (SELECT CASE WHEN round_stats.avg_damage_taken = 0 THEN round_stats.avg_damage_done
+ ELSE (round_stats.avg_damage_done/round_stats.avg_damage_taken) END as avg_damage
+ FROM round_stats WHERE round_stats.round_id=_round_id) rs
+ WHERE
+ player.id=prs.player_id AND
+ prs.player_damage > rs.avg_damage
+
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_AverageDamageDone.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Did more damage than the average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Acceptable Combat Performance' ,
+
+-- Trophy Description
+'Did better than the average attack of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.damage_done > round_stats.avg_damage_done
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_AverageDistanceCovered.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Distance Covered is greater than average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Scout' ,
+
+-- Trophy Description
+'Covered more distance than the average of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.distance_travelled > round_stats.avg_distance_travelled
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
54 trophies/trophy_AverageFleetSize.sql
@@ -0,0 +1,54 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Larger Fleet Size than average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Superpower' ,
+
+-- Trophy Description
+'The players fleet size is greater than the average'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player.id as player_id
+ FROM
+ player,
+ (SELECT player_round_stats.player_id,
+ ships_built-ships_lost as player_ships
+ FROM player_round_stats WHERE player_round_stats.round_id = _round_id) prs,
+ (SELECT avg_ships_built-avg_ships_lost as avg_ships
+ FROM round_stats WHERE round_stats.round_id=_round_id) rs
+ WHERE
+ player.id=prs.player_id AND
+ prs.player_ships > rs.avg_ships
+
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_AverageFuelMined.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Did more fuel mining than the average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Big Petroleum' ,
+
+-- Trophy Description
+'Did better than the average mining of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.fuel_mined > round_stats.avg_fuel_mined
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
56 trophies/trophy_AveragePlanetsMaintained.sql
@@ -0,0 +1,56 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Maintained control over more than the average number of planets
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Solid Leadership' ,
+
+-- Trophy Description
+'Had an empire at least larger than average during the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player.id as player_id
+ FROM
+ player,
+ (SELECT player_round_stats.player_id,
+ CASE WHEN player_round_stats.planets_lost = 0 THEN player_round_stats.planets_conquered
+ ELSE (player_round_stats.planets_conquered / player_round_stats.planets_lost) END as player_planets
+ FROM player_round_stats WHERE player_round_stats.round_id = _round_id) prs,
+ (SELECT CASE WHEN round_stats.avg_planets_lost = 0 THEN round_stats.avg_planets_conquered
+ ELSE (round_stats.avg_planets_conquered/round_stats.avg_planets_lost) END as avg_planets
+ FROM round_stats WHERE round_stats.round_id=_round_id) rs
+ WHERE
+ player.id=prs.player_id AND
+ prs.player_planets > rs.avg_planets
+
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
56 trophies/trophy_BelowAverageAttackVSDamageRatio.sql
@@ -0,0 +1,56 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Below Attack/Damage ratio average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Crap Combat Performance' ,
+
+-- Trophy Description
+'The players Attack done VS Damage Taken ratio is lower than the average'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player.id as player_id
+ FROM
+ player,
+ (SELECT player_round_stats.player_id,
+ CASE WHEN player_round_stats.damage_taken = 0 THEN player_round_stats.damage_done
+ ELSE (player_round_stats.damage_done / player_round_stats.damage_taken) END as player_damage
+ FROM player_round_stats WHERE player_round_stats.round_id = _round_id) prs,
+ (SELECT CASE WHEN round_stats.avg_damage_taken = 0 THEN round_stats.avg_damage_done
+ ELSE (round_stats.avg_damage_done/round_stats.avg_damage_taken) END as avg_damage
+ FROM round_stats WHERE round_stats.round_id=_round_id) rs
+ WHERE
+ player.id=prs.player_id AND
+ prs.player_damage < rs.avg_damage
+
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_BelowAverageDamageDone.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Did less damage than the average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Unacceptable Combat Performance' ,
+
+-- Trophy Description
+'Did worse than the average attack of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.damage_done < round_stats.avg_damage_done
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_BelowAverageDistanceCovered.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Distance Covered is below average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Fuel Conservationist' ,
+
+-- Trophy Description
+'Covered less distance than the average of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.distance_travelled < round_stats.avg_distance_travelled
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
54 trophies/trophy_BelowAverageFleetSize.sql
@@ -0,0 +1,54 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Smaller Fleet Size than average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Annoyance' ,
+
+-- Trophy Description
+'The players fleet size is less than the average'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player.id as player_id
+ FROM
+ player,
+ (SELECT player_round_stats.player_id,
+ ships_built-ships_lost as player_ships
+ FROM player_round_stats WHERE player_round_stats.round_id = _round_id) prs,
+ (SELECT avg_ships_built-avg_ships_lost as avg_ships
+ FROM round_stats WHERE round_stats.round_id=_round_id) rs
+ WHERE
+ player.id=prs.player_id AND
+ prs.player_ships < rs.avg_ships
+
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_BelowAverageFuelMined.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Did less fuel mining than the average
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Corner Gas' ,
+
+-- Trophy Description
+'Did worse than the average mining of all players in the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-50,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.fuel_mined < round_stats.avg_fuel_mined
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
51 trophies/trophy_BelowAverageUpgrades.sql
@@ -0,0 +1,51 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Below Average Upgrades
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Penny Pincher' ,
+
+-- Trophy Description
+'Could not provide their fleet with the equipment they need'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-500,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+FOR players IN
+ SELECT
+ player_round_stats.player_id
+ FROM
+ player_round_stats, round_stats
+ WHERE
+ player_round_stats.round_id = _round_id
+ AND
+ round_stats.round_id = _round_id
+ AND
+ player_round_stats.ship_upgrades < round_stats.avg_ship_upgrades
+LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+END LOOP;
+'
+);
+
View
59 trophies/trophy_FinalStandings_1st.sql
@@ -0,0 +1,59 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Final Standings - First Place
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Schema Supremacy' ,
+
+-- Trophy Description
+'Round champion. All hail your Schemaverse overlord'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+0,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+999,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+FOR players IN
+ SELECT
+ player_trophy.player_id,
+ sum(trophy.weight) as total
+ FROM
+ player_trophy, trophy
+ WHERE
+ player_trophy.round=_round_id
+ AND player_trophy.trophy_id=trophy.id
+ GROUP BY player_trophy.player_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+
+'
+);
+
View
68 trophies/trophy_FirstBlood.sql
@@ -0,0 +1,68 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: First Blood
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'First Blood' ,
+
+-- Trophy Description
+'First attack of the round!'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+',
+--BEGIN
+'
+
+IF _round_id = this_round THEN
+ FOR players IN
+ SELECT
+ player_id_1
+ FROM
+ event
+ WHERE
+ action=''ATTACK''
+ ORDER BY id ASC LIMIT 1
+ LOOP
+ winner.round := this_round;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id_1;
+ RETURN NEXT winner;
+ END LOOP;
+ELSE
+ FOR players IN
+ SELECT
+ player_id_1
+ FROM
+ event_archive
+ WHERE
+ action=''ATTACK''
+ AND round_id=_round_id
+ ORDER BY event_id ASC LIMIT 1
+ LOOP
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id_1;
+ RETURN NEXT winner;
+ END LOOP;
+
+END IF;
+'
+);
+
View
57 trophies/trophy_LeastConqueredPlanets.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Least Planets Conquered
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'No place like Home' ,
+
+-- Trophy Description
+'This player conquered the least amount of planets during the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ planets_conquered as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total ASC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_LeastDamageDone.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Least Damage Done
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Peacekeeper' ,
+
+-- Trophy Description
+'Maybe you should invest in defense.. or maybe you did already... This goes to the player who dealt the least damage throughout the round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ damage_done as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total ASC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_LeastDistanceCovered.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Least Distance Covered
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Hermit' ,
+
+-- Trophy Description
+'This player travelled the least distance overall in a round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-200,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ distance_travelled as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total ASC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_LeastFuelMined.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Least Fuel Mined
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Greenpeace' ,
+
+-- Trophy Description
+'This goes to the player who mined the least fuel throughout the round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ fuel_mined as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total ASC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_LeastShips.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Least Ships
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Least Ships' ,
+
+-- Trophy Description
+'This player had the smallest fleet of ships in a round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ ships_built-ships_lost as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total ASC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostConqueredPlanets.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Planets Conquered
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Greatest Empire' ,
+
+-- Trophy Description
+'This player conquered the most amount of planets during the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+200,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ planets_conquered as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostDamageDone.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Damage Done
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Space Jerk' ,
+
+-- Trophy Description
+'You might get picked on after winning this trophy. This goes to the player who dealt the most damage throughout the round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ damage_done as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostDamageTaken.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Damage Taken
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Peacekeeper''s Sidekick' ,
+
+-- Trophy Description
+'Maybe you should invest in defense.. or maybe you did already... This goes to the player who took the most damage throughout the round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ damage_taken as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostDistanceCovered.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Distance Covered
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Discoverer' ,
+
+-- Trophy Description
+'This player travelled the furthest distance overall in a round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+200,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ distance_travelled as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostFuelMined.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Fuel Mined
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Oil Tycoon' ,
+
+-- Trophy Description
+'This goes to the player who mined the most fuel throughout the round.'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ fuel_mined as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostPlanetsLost.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Planets Lost
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Coward' ,
+
+-- Trophy Description
+'This player lost the most amount of planets to another during the round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ planets_lost as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostPowerfulShips.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Powerful Ships
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Size Matters' ,
+
+-- Trophy Description
+'This player had the most powerful fleet of ships in a round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+200,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ ship_upgrades as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostShips.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Ships
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Largest Fleet' ,
+
+-- Trophy Description
+'This player had the largest fleet of ships in a round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ ships_built-ships_lost as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
57 trophies/trophy_MostShipsDestroyed.sql
@@ -0,0 +1,57 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Most Ships Destroyed
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'Space Lemmings' ,
+
+-- Trophy Description
+'Had the most ships destroyed within a round'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+-100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,
+
+-- Trophy Script Definition
+-- DECLARE
+'
+players RECORD;
+winning_total bigint;
+',
+--BEGIN
+'
+winning_total := 0;
+
+FOR players IN
+ SELECT
+ player_id,
+ ships_lost as total
+ FROM
+ player_round_stats
+ WHERE
+ round_id=_round_id
+ ORDER BY total DESC
+LOOP
+ IF winning_total = 0 OR winning_total = players.total THEN
+ winning_total := players.total;
+ winner.round := _round_id;
+ winner.trophy_id := this_trophy_id;
+ winner.player_id := players.player_id;
+ RETURN NEXT winner;
+ ELSE
+ RETURN;
+ END IF;
+END LOOP;
+'
+);
+
View
64 trophies/trophy_Participation.sql
@@ -0,0 +1,64 @@
+-- The Schemaverse
+-- Trophy Creation Script
+-- Created by Josh McDougall
+--
+-- Trophy Goal: Participation
+
+INSERT INTO trophy (name, description, weight, run_order, script_declarations, script )
+VALUES(
+
+-- Trophy Common Name
+'The Participation Award' ,
+
+-- Trophy Description
+'Great work. You certainly signed up!'::TEXT,
+
+-- Weight
+-- This is the amount of points the trophy is worth. Can be any value between -32768 to +32767
+100,
+
+-- Run Order
+-- This is the order the trophy will be calculated in (In ascending order).
+-- Unless the trophy relies on the amount of other trophies won, this should likely be 0
+0,