Thu Sep 6 09:09:56 PDT 2007
- Previous message: [Slony1-commit] slony1-engine/src/backend slony1_funcs.sql
- Next message: [Slony1-commit] slony1-engine/tests/testpartition README gen_ddl_sql.sh generate_dml.sh schema.diff
- Messages sorted by: [ date ] [ thread ] [ subject ] [ author ]
Update of /home/cvsd/slony1/slony1-engine/tests/testpartition In directory main.slony.info:/tmp/cvs-serv21314 Added Files: Tag: REL_1_2_STABLE README gen_ddl_slonik.sh gen_ddl_sql.sh generate_dml.sh init_add_tables.ik init_cluster.ik init_create_set.ik init_data.sql init_schema.sql init_subscribe_set.ik schema.diff settings.ik Log Message: Add partitioning test to 1.2 branch --- NEW FILE: settings.ik --- NUMCLUSTERS=${NUMCLUSTERS:-"1"} NUMNODES=${NUMNODES:-"2"} ORIGINNODE=1 WORKERS=${WORKERS:-"1"} --- NEW FILE: init_cluster.ik --- init cluster (id=1, comment = 'Regress test node'); --- NEW FILE: generate_dml.sh --- . support_funcs.sh init_dml() { echo "init_dml()" } begin() { echo "begin()" } rollback() { echo "rollback()" } commit() { echo "commit()" } more_data () { GENDATA="$mktmp/generate.data" #for year in 2006 2007 2008 2009 2010 2011 2012; do for year in 2006 ; do #for month in 1 2 3 4 5 6 7 8 9 10 11 12; do for month in 1 2 3 ; do echo "" > ${GENDATA} numrows=$(random_number 50 75) status "Generating ${numrows} transactions of random data for ${year}/${month}" i=0 while : ; do if [ ${i} -ge ${numrows} ]; then break; else i=$((${i} +1)) fi quantity=$(random_number 1 9) day=$(random_number 1 25) # Peculiar company that closes up the last few days of the month hour=$(random_number 8 19) # sells during "human" hours of the day in London minute=$(random_number 1 59) echo "select purchase_product (region_code, product_id, (${quantity}+random()*3)::integer, '${year}-${month}-${day} ${hour}:${minute} GMT'::timestamptz) from regions, products order by random() limit 3;" >> ${GENDATA} done size=`wc -l ${GENDATA}` status "got data for ${year}/${month} - ${size} items" status "Generate DDL script for new partition for ${year}/${month}" DDLSQL=$mktmp/ddl_script_${year}_${month}.sql SCRIPT=$mktmp/slonik.script init_preamble sh ${testname}/gen_ddl_sql.sh ${year} ${month} ${CLUSTER1} > ${DDLSQL} sh ${testname}/gen_ddl_slonik.sh ${DDLSQL} >> ${SCRIPT} do_ik status "Added new partition for ${year}/${month}" status "Load data for ${year}/${month}" eval db=\$DB${originnode} $pgbindir/psql -h $host -p $port -d $db -U $user < ${GENDATA} 1>> $mktmp/loaddata_${year}_${month}.log 2>> $mktmp/loaddata_${year}_${month}.log done done status "done" } do_initdata() { originnode=${ORIGINNODE:-"1"} eval db=\$DB${originnode} eval host=\$HOST${originnode} eval user=\$USER${originnode} eval port=\$PORT${originnode} # generate_initdata - # No initial data! launch_poll status "loading data" #$pgbindir/psql -h $host -p $port -d $db -U $user < $mktmp/generate.data 1> $mktmp/initdata.log 2> $mktmp/initdata.log if [ $? -ne 0 ]; then warn 3 "do_initdata failed, see $mktmp/initdata.log for details" fi wait_for_catchup status "done" more_data } --- NEW FILE: gen_ddl_slonik.sh --- ddlfile=$1 echo " EXECUTE SCRIPT ( SET ID = 1, FILENAME = '${ddlfile}', EVENT NODE = 1 ); " --- NEW FILE: init_add_tables.ik --- set add table (id=1, set id=1, origin=1, fully qualified name = 'public.regions', comment='regions table'); set add table (id=2, set id=1, origin=1, fully qualified name = 'public.products', comment='product table'); set add table (id=3, set id=1, origin=1, fully qualified name = 'public.sales_txns', comment='Global sales transactions'); --- NEW FILE: gen_ddl_sql.sh --- year=$1 month=$2 cluster=$3 # We're looking for what month and year follow year/month by 1 month nextmonth=$((${month} +1)) nextmonthsyear=${year} if [ ${nextmonth} -ge 13 ]; then nextmonth=1 nextmonthsyear=$((${year} +1)) fi tableid=`printf "%04d%02d" ${year} ${month}` echo " create table sales_txns_${year}_${month} ( check (trans_on >= '${year}-${month}-01' and trans_on < '${nextmonthsyear}-${nextmonth}-01'), primary key(id) ) inherits (sales_txns); create rule sales_${year}_${month} as on insert to sales_txns where trans_on >= '${year}-${month}-01' and trans_on < '${nextmonthsyear}-${nextmonth}-01' do instead ( insert into sales_txns_${year}_${month} select new.id, new.trans_on, new.region_code, new.product_id, new.quantity, new.amount; ); select \"_${cluster}\".replicate_partition(${tableid}, 'public'::text, 'sales_txns_${year}_${month}'::text, NULL::text, 'Sales Partition for ${year} ${month}'::text); " --- NEW FILE: init_create_set.ik --- create set (id=1, origin=1, comment='All test1 tables'); --- NEW FILE: init_data.sql --- insert into regions (region_code, iso_country, region, city) values (1001, 'US', 'NY', 'New York City'); insert into regions (region_code, iso_country, region, city) values (1002, 'US', 'NY', 'Albany'); insert into regions (region_code, iso_country, region, city) values (1003, 'US', 'MA', 'Boston'); insert into regions (region_code, iso_country, region, city) values (1004, 'US', 'PH', 'Philadelphia'); insert into regions (region_code, iso_country, region, city) values (1005, 'US', 'DC', 'Washington'); insert into regions (region_code, iso_country, region, city) values (1006, 'US', 'GA', 'Atlanta'); insert into regions (region_code, iso_country, region, city) values (1007, 'US', 'FL', 'Miami'); insert into regions (region_code, iso_country, region, city) values (1008, 'US', 'ME', 'Portland'); insert into regions (region_code, iso_country, region, city) values (2000, 'US', 'OR', 'Portland'); insert into regions (region_code, iso_country, region, city) values (2001, 'US', 'CA', 'Los Angeles'); insert into regions (region_code, iso_country, region, city) values (2002, 'US', 'CA', 'San Francisco'); insert into regions (region_code, iso_country, region, city) values (2003, 'US', 'NV', 'Las Vegas'); insert into regions (region_code, iso_country, region, city) values (2004, 'US', 'CA', 'San Diego'); insert into regions (region_code, iso_country, region, city) values (2005, 'US', 'WA', 'Seattle'); insert into regions (region_code, iso_country, region, city) values (3000, 'CA', 'ON', 'Ottawa'); insert into regions (region_code, iso_country, region, city) values (3001, 'CA', 'ON', 'Toronto'); insert into regions (region_code, iso_country, region, city) values (3002, 'CA', 'NS', 'Halifax'); insert into regions (region_code, iso_country, region, city) values (3003, 'CA', 'AB', 'Calgary'); insert into regions (region_code, iso_country, region, city) values (3004, 'CA', 'BC', 'Vancouver'); insert into regions (region_code, iso_country, region, city) values (4000, 'GB', NULL, 'London'); insert into regions (region_code, iso_country, region, city) values (4001, 'DE', NULL, 'Munich'); insert into regions (region_code, iso_country, region, city) values (4002, 'FR', NULL, 'Paris'); insert into regions (region_code, iso_country, region, city) values (4003, 'IT', NULL, 'Rome'); insert into regions (region_code, iso_country, region, city) values (4004, 'EG', NULL, 'Cairo'); insert into regions (region_code, iso_country, region, city) values (4005, 'JP', NULL, 'Tokyo'); insert into regions (region_code, iso_country, region, city) values (4006, 'CH', NULL, 'Bejing'); insert into regions (region_code, iso_country, region, city) values (4007, 'AU', NULL, 'Melbourne'); insert into products (name, price) values ('Batarang', 275.00); insert into products (name, price) values ('Bat Rope', 17.55); insert into products (name, price) values ('Bat Belt', 24.99); insert into products (name, price) values ('Blaster', 488.95); insert into products (name, price) values ('Phased Plasma Rifle (40W)', 823.95); insert into products (name, price) values ('Holy Hand Grenade of Antioch', 182.44); insert into products (name, price) values ('BFG 9000', 2788.05); insert into products (name, price) values ('Cell Phone', 281.00); insert into products (name, price) values ('Cone of Silence', 2481.00); insert into products (name, price) values ('Shoe Phone', 175.00); insert into products (name, price) values ('Umbrella of Silence', 3500.00); insert into products (name, price) values ('Bunsen Burner Phone', 182.50); insert into products (name, price) values ('Gun Phone', 352.75); select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-15') from regions, products order by random() limit 3; select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-16') from regions, products order by random() limit 3; select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-17') from regions, products order by random() limit 3; select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-18') from regions, products order by random() limit 3; select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-19') from regions, products order by random() limit 3; select purchase_product( region_code, product_id, (random()*5+random()*8+random()*7)::integer, '2006-01-20') from regions, products order by random() limit 3; --- NEW FILE: init_schema.sql --- create table regions ( region_code integer primary key, iso_country char(2), region text, city text ); create unique index region_names on regions(iso_country, region, city); create table products ( product_id serial primary key, name text unique not null, price numeric(10,2) not null ); create table sales_txns ( id serial primary key not null, trans_on timestamptz not null default 'now()', region_code integer not null references regions(region_code), product_id integer not null references products(product_id), quantity integer not null, amount numeric(12,2) not null ); create or replace function sales_trig_ins () returns trigger as ' begin raise exception ''Missing sales_txns partition for date %'', new.trans_on; end; ' language plpgsql; create trigger sales_txn_ins before insert on sales_txns for each row execute procedure sales_trig_ins(); create rule sales_txn_update as on update to sales_txns where new.trans_on <> old.trans_on do instead ( insert into sales_txns (id,trans_on,region_code,product_id,quantity,amount) values (new.id, new.trans_on, new.region_code, new.product_id, new.quantity, new.amount); delete from sales_txns where id = old.id; ); -- We will be doing inserts into sales_txns inside the following stored proc create or replace function purchase_product (integer, integer, integer, timestamptz) returns numeric(12,2) as ' declare i_region alias for $1; i_product alias for $2; i_quantity alias for $3; i_txndate alias for $4; c_price numeric(10,2); c_amount numeric(12,2); begin select price into c_price from products where product_id = i_product; c_amount := c_price * i_quantity; insert into sales_txns (region_code, product_id, quantity, amount, trans_on) values (i_region, i_product, i_quantity, c_amount, i_txndate); return c_amount; end' language plpgsql; --- NEW FILE: schema.diff --- select id, trans_on, quantity, amount from sales_txns order by id select 'main', * from only sales_txns order by id select '2006_1', * from sales_txns_2006_1 order by id select '2006_2', * from sales_txns_2006_2 order by id select '2006_3', * from sales_txns_2006_3 order by id select '2006_4', * from sales_txns_2006_4 order by id --- NEW FILE: README --- $Id: README,v 1.1.2.1 2007-09-06 16:09:54 cbbrowne Exp $ testpartition sets up a partitioning test, periodically adding new partitions. --- NEW FILE: init_subscribe_set.ik --- subscribe set (id = 1, provider = 1, receiver = 2, forward = no);
- Previous message: [Slony1-commit] slony1-engine/src/backend slony1_funcs.sql
- Next message: [Slony1-commit] slony1-engine/tests/testpartition README gen_ddl_sql.sh generate_dml.sh schema.diff
- Messages sorted by: [ date ] [ thread ] [ subject ] [ author ]
More information about the Slony1-commit mailing list