├── .gitignore ├── LICENSE ├── README.md ├── anim.sh ├── create.sh ├── debug_rays.sh ├── example_outputs ├── adjacentballs.png ├── dielectricparty.png ├── oneglassball.png ├── onegreenball.png ├── onegreyball.png ├── onemirrorball.png ├── reflectiontest.png ├── threemirrors.png ├── twodiffuseballs.png └── twomirrorballs.png ├── postgres_connection.sh ├── raytracer.sql └── setup.sql /.gitignore: -------------------------------------------------------------------------------- 1 | debug_rays 2 | scenelist.txt 3 | *.ppm 4 | anim 5 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2021 Gary Briggs 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy 4 | of this software and associated documentation files (the "Software"), to deal 5 | in the Software without restriction, including without limitation the rights 6 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 7 | copies of the Software, and to permit persons to whom the Software is 8 | furnished to do so, subject to the following conditions: 9 | 10 | The above copyright notice and this permission notice shall be included in all 11 | copies or substantial portions of the Software. 12 | 13 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 14 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 15 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 16 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 17 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 18 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 19 | SOFTWARE. 20 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # A Pure SQL Raytracer 2 | 3 | Everyone writes a raytracer sooner or later. This is mine. 4 | 5 | ## Example Outputs 6 | 7 | 8 | 9 | ## Usage 10 | 11 | ```shell 12 | sh create.sh 13 | ``` 14 | 15 | ```postgres_connection.sh``` contains host/database/user/pass/etc. 16 | There are no exotic needs other than "postgres, like version 10 and up 17 | or something" 18 | 19 | For what it's worth, I created mine thus on my ubuntu desktop: 20 | ```shell 21 | sudo su - postgres 22 | createuser --pwprompt raytracer 23 | createdb -O raytracer raytracer 24 | ``` 25 | 26 | ### Levers for development and rendering 27 | 28 | While doing development, obviously a few-minute render time is a pretty 29 | poor cycle time. There are a few levers you can pull to speed things up 30 | and reduce quality. They're on "camera" and "img" in setup.sql: 31 | 32 | * *samples\_per\_px* - This is the number of rays/sub-samples per pixel. 33 | - 1 or 2 is fine during debugging 34 | - 15-20 gives "workable" pictures 35 | - Going above 50 doesn't generate much visible improvement 36 | * *max\_ray\_depth* - The maximum number of ray bounces 37 | - For simple scenes, it usually makes no more than 5 or so bounces 38 | * *res\_x* and *res\_y* - Final image resolution 39 | - Smaller is faster 40 | 41 | The main CTE carries a lot of stuff that's unnecessary to final output. 42 | This is so I can examine rays bouncing through the scene with: 43 | ```sql 44 | SELECT * FROM rays WHERE img_x=100 AND img_y=250 45 | ``` 46 | 47 | ## Database 48 | 49 | This is implemented in pure SQL. It doesn't do anything like CREATE 50 | FUNCTION or other nonportables, except for the trigger to do animation, 51 | which obviously doesn't count. 52 | 53 | At the same time, there are some not-entirely-common features of SQL 54 | that it needs: 55 | 56 | * JOIN LATERAL 57 | * PARTITION BY inside of a RECURSIVE CTE 58 | * Math functions like SIN() 59 | 60 | So although I started developing this in SQLite, I ended up leaning 61 | on PostgreSQL. As I write this, it works in postgres and hasn't been 62 | tested in anything else. 63 | 64 | ## Interesting Implementation Pieces 65 | 66 | Such as it is, I did find myself solving some problems in interesting 67 | ways. 68 | 69 | ### JOIN LATERAL 70 | 71 | JOIN LATERAL is a way to do a correlated subquery in a JOIN, instead of 72 | just in a WHERE clause. I use this as a way to hoist calculations and 73 | do many of them only once and, in some cases, avoid excessive duplication. 74 | 75 | ### Diffuse Scattering 76 | 77 | This requires sampling a uniform sphere. I generate a lot of random 78 | samples ahead of time [sample with rejection -> scale points to sphere 79 | surface], and number them. 80 | 81 | Figuring out a way to join each ray to a single random row from these 82 | precalculated scatters was weird; can't just join to RANDOM() because 83 | every ray got joined to the same, random, scatter. Can't just select 84 | with a typical calculation on a normal because that leads to stripes 85 | in the picture. So, instead, I schlep out a later few decimals of one 86 | dimension of a normal, then join to that. It's "random" but also 87 | unique-enough-per-ray. 88 | 89 | ### Recursive CTEs 90 | 91 | Raytracing very naturally tracks how recursive CTEs work. One of the 92 | things I ran into was a clean way to identify which ray is the one to 93 | account for. Using a window function ordering by intercept (t) worked 94 | well. Every iteration, this query intersects a ray with *everything* 95 | in front of it and does all of the associated calculations, but then in 96 | the WHERE clause will reject everything except the thing the ray 97 | actually hit. 98 | 99 | Also, there's something really beautiful about the simplicity of the 100 | core of the final rollup [edited for clarity]: 101 | ```sql 102 | SELECT img_x, img_y, 103 | SUM(POW(color_mult * ray_col_r/samples_per_px, gamma)) col_r, 104 | SUM(POW(color_mult * ray_col_g/samples_per_px, gamma)) col_g, 105 | SUM(POW(color_mult * ray_col_b/samples_per_px, gamma)) col_b 106 | FROM rays 107 | GROUP BY img_y, img_x 108 | ``` 109 | 110 | ### Scenes, materials, etc 111 | 112 | Because this is in SQL, I can store multiple scenes in the database. Which 113 | one is actually rendered is selected in the "camera" table. 114 | 115 | ## Standing on the Necks of Giants 116 | 117 | Two years before I wrote this "The most advanced MySQL raytracer on the 118 | market right now" did the rounds on social media: 119 | https://www.pouet.net/prod.php?which=83222 120 | 121 | I had a few things in mind that I wanted to do differently [worse?]: 122 | 123 | * Demoscene is an artform. I'm not golfing, this isn't minified 124 | * Not a single query; that can be done with CTEs, but ehhhhhhhh 125 | * Animation as an endgame 126 | * Mainly, I'm just buggering around with the wrong tool for the job 127 | 128 | ## References 129 | 130 | Most of this is built following the "Ray Tracing in One Weekend" 131 | series: https://raytracing.github.io/ , then making allowances for 132 | the deliberately obtuse way I'm coding it. 133 | 134 | 135 | Gary 136 | 137 | -------------------------------------------------------------------------------- /anim.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | . ./postgres_connection.sh 4 | 5 | scenename="busyday" 6 | outfolder=anim 7 | dt=0.05 8 | gravity=-9.8 9 | 10 | psql \ 11 | --host=${PGHOST} \ 12 | --port=${PGPORT} \ 13 | --username=${PGUSER} \ 14 | --dbname=${PGDB} \ 15 | --file=setup.sql \ 16 | --file=raytracer.sql \ 17 | --command="UPDATE camera SET sceneid=(SELECT sceneid FROM scene WHERE scenename='${scenename}')" 18 | 19 | mkdir -p ${outfolder} 20 | 21 | for frame in `seq -w 0 1000` 22 | do 23 | echo "Frame ${frame}" 24 | psql \ 25 | --host=${PGHOST} \ 26 | --port=${PGPORT} \ 27 | --username=${PGUSER} \ 28 | --dbname=${PGDB} \ 29 | --command="INSERT INTO updateworld(dt, grav_x, grav_y, grav_z) VALUES (${dt}, 0.0, ${gravity}, 0.0)" \ 30 | --command="\\timing" \ 31 | --command="\\copy (select * from ppm) to './${outfolder}/${scenename}_${frame}.ppm' csv" 32 | 33 | done 34 | 35 | ffmpeg \ 36 | -r 25 \ 37 | -i ./${outfolder}/${scenename}_%d.ppm \ 38 | -vcodec libx264 \ 39 | -crf 25 \ 40 | -pix_fmt yuv420p \ 41 | ./${outfolder}/${scenename}.mp4 42 | 43 | -------------------------------------------------------------------------------- /create.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | . ./postgres_connection.sh 4 | 5 | # Creating this file overrides which scenes get rendered 6 | scenelist_override=scenelist_override.txt 7 | 8 | scenelist=scenelist.txt 9 | 10 | outputdir=example_outputs 11 | 12 | mkdir -p ${outputdir} 13 | 14 | psql \ 15 | --host=${PGHOST} \ 16 | --port=${PGPORT} \ 17 | --username=${PGUSER} \ 18 | --dbname=${PGDB} \ 19 | --file=setup.sql \ 20 | --file=raytracer.sql \ 21 | --command="\\timing" \ 22 | --command="\\copy (select scenename from scene) to './${outputdir}/${scenelist}' csv" 23 | 24 | test -e ${scenelist_override} && cp ${scenelist_override} ${outputdir}/${scenelist} 25 | 26 | while read scenename 27 | do 28 | echo "" 29 | echo "Rendering scene ${scenename}" 30 | psql \ 31 | --host=${PGHOST} \ 32 | --port=${PGPORT} \ 33 | --username=${PGUSER} \ 34 | --dbname=${PGDB} \ 35 | --command="UPDATE camera SET sceneid=(SELECT sceneid FROM scene WHERE scenename='${scenename}')" \ 36 | --command="\\timing" \ 37 | --command="\\copy (select * from ppm) to './${outputdir}/${scenename}.ppm' csv" 38 | 39 | if [ "$(uname)" == "Darwin" ]; then 40 | open ./${outputdir}/${scenename}.ppm 41 | else 42 | xdg-open ./${outputdir}/${scenename}.ppm 43 | fi 44 | 45 | convert ./${outputdir}/${scenename}.ppm ./${outputdir}/${scenename}.png 46 | 47 | done < ./${outputdir}/${scenelist} 48 | 49 | -------------------------------------------------------------------------------- /debug_rays.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | . ./postgres_connection.sh 4 | 5 | debug_dir=debug_rays 6 | mkdir -p ${debug_dir} 7 | cd ${debug_dir} 8 | 9 | psql \ 10 | --host=${PGHOST} \ 11 | --port=${PGPORT} \ 12 | --username=${PGUSER} \ 13 | --dbname=${PGDB} \ 14 | --command="\\copy (select sphereid, cx, cy, cz, radius from sphere inner join camera c ON c.sceneid=sphere.sceneid) to './spheres.csv' with csv header" \ 15 | --command="\\copy (select * from rays WHERE img_x=125 AND img_y between 120 and 195 and 0=img_y%5) to './rays.csv' with csv header" 16 | 17 | img_size=1024 18 | 19 | scale_vector=5 20 | 21 | cat < gnuplot.gp 22 | set terminal png size ${img_size},${img_size} 23 | set xrange [-60:60] 24 | set yrange [-60:60] 25 | set datafile separator ',' 26 | set key autotitle columnhead 27 | 28 | set output 'debug_rays_xz.png' 29 | set xlabel "X" 30 | set ylabel "Z" 31 | plot \\ 32 | "spheres.csv" u 2:4:5 w circles t 'spheres', \\ 33 | "rays.csv" u 12:14:(${scale_vector}*\$19/\$22):(${scale_vector}*\$21/\$22) w vectors t 'normals', \\ 34 | "rays.csv" u 12:14:(${scale_vector}*\$15):(${scale_vector}*\$17) w vectors filled head t 'rays' 35 | 36 | set output 'debug_rays_zx.png' 37 | set xlabel "Z" 38 | set ylabel "X" 39 | plot \\ 40 | "spheres.csv" u 4:2:5 w circles t 'spheres', \\ 41 | "rays.csv" u 14:12:(${scale_vector}*\$21/\$22):(${scale_vector}*\$19/\$22) w vectors t 'normals', \\ 42 | "rays.csv" u 14:12:(${scale_vector}*\$17):(${scale_vector}*\$15) w vectors filled head t 'rays' 43 | 44 | set output 'debug_rays_xy.png' 45 | set xlabel "X" 46 | set ylabel "Y" 47 | plot \\ 48 | "spheres.csv" u 2:3:5 w circles t 'spheres', \\ 49 | "rays.csv" u 12:13:(${scale_vector}*\$19/\$22):(${scale_vector}*\$20/\$22) w vectors t 'normals', \\ 50 | "rays.csv" u 12:13:(${scale_vector}*\$15):(${scale_vector}*\$16) w vectors t 'rays' 51 | 52 | set output 'debug_rays_yx.png' 53 | set xlabel "Y" 54 | set ylabel "X" 55 | plot \\ 56 | "spheres.csv" u 3:2:5 w circles t 'spheres', \\ 57 | "rays.csv" u 13:12:(${scale_vector}*\$20/\$22):(${scale_vector}*\$19/\$22) w vectors t 'normals', \\ 58 | "rays.csv" u 13:12:(${scale_vector}*\$16):(${scale_vector}*\$15) w vectors t 'rays' 59 | 60 | set output 'debug_rays_yz.png' 61 | set xlabel "Y" 62 | set ylabel "Z" 63 | plot \\ 64 | "spheres.csv" u 3:4:5 w circles t 'spheres', \ 65 | "rays.csv" u 13:14:(${scale_vector}*\$20/\$22):(${scale_vector}*\$21/\$22) w vectors t 'normals', \\ 66 | "rays.csv" u 13:14:(${scale_vector}*\$16):(${scale_vector}*\$17) w vectors t 'rays' 67 | 68 | set output 'debug_rays_zy.png' 69 | set xlabel "Z" 70 | set ylabel "Y" 71 | plot \\ 72 | "spheres.csv" u 4:3:5 w circles t 'spheres', \\ 73 | "rays.csv" u 14:13:(${scale_vector}*\$21/\$22):(${scale_vector}*\$20/\$22) w vectors t 'normals', \\ 74 | "rays.csv" u 14:13:(${scale_vector}*\$17):(${scale_vector}*\$16) w vectors t 'rays' 75 | 76 | set output '3view.png' 77 | set xrange [-120:120] 78 | set yrange [-120:120] 79 | set zrange [-120:120] 80 | set xlabel "X" 81 | set ylabel "Y" 82 | set zlabel "Z" 83 | splot \\ 84 | "spheres.csv" u 2:3:4:5 w circles t 'spheres', \\ 85 | "rays.csv" u 12:13:14:(${scale_vector}*\$19/\$22):(${scale_vector}*\$20/\$22):(${scale_vector}*\$21/\$22) w vectors filled head t 'normals', \\ 86 | "rays.csv" u 12:13:14:(${scale_vector}*\$15):(${scale_vector}*\$16):(${scale_vector}*\$17) w vectors filled head t 'rays' 87 | 88 | set terminal qt 89 | replot 90 | 91 | EOH 92 | 93 | gnuplot gnuplot.gp 94 | 95 | montage \ 96 | -tile 2x2 \ 97 | -geometry ${img_size}x${img_size} \ 98 | debug_rays_xy.png \ 99 | debug_rays_zy.png \ 100 | debug_rays_xz.png \ 101 | 3view.png \ 102 | debug_rays.png 103 | 104 | xdg-open debug_rays.png 105 | 106 | -------------------------------------------------------------------------------- /example_outputs/adjacentballs.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/adjacentballs.png -------------------------------------------------------------------------------- /example_outputs/dielectricparty.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/dielectricparty.png -------------------------------------------------------------------------------- /example_outputs/oneglassball.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/oneglassball.png -------------------------------------------------------------------------------- /example_outputs/onegreenball.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/onegreenball.png -------------------------------------------------------------------------------- /example_outputs/onegreyball.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/onegreyball.png -------------------------------------------------------------------------------- /example_outputs/onemirrorball.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/onemirrorball.png -------------------------------------------------------------------------------- /example_outputs/reflectiontest.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/reflectiontest.png -------------------------------------------------------------------------------- /example_outputs/threemirrors.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/threemirrors.png -------------------------------------------------------------------------------- /example_outputs/twodiffuseballs.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/twodiffuseballs.png -------------------------------------------------------------------------------- /example_outputs/twomirrorballs.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/chunky/sqlraytracer/86bfa1d47a0820afdf99fc84865b52feeb2faee3/example_outputs/twomirrorballs.png -------------------------------------------------------------------------------- /postgres_connection.sh: -------------------------------------------------------------------------------- 1 | PGHOST=localhost 2 | PGPORT=5432 3 | PGUSER=raytracer 4 | PGDB=raytracer 5 | 6 | PGPASSWORD=raytracer 7 | export PGPASSWORD 8 | 9 | -------------------------------------------------------------------------------- /raytracer.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS sphere_sample CASCADE; 2 | CREATE TABLE IF NOT EXISTS sphere_sample (x DOUBLE PRECISION NOT NULL, y DOUBLE PRECISION NOT NULL, z DOUBLE PRECISION NOT NULL, 3 | a DOUBLE PRECISION NOT NULL, b DOUBLE PRECISION NOT NULL, c DOUBLE PRECISION NOT NULL, sampleno INTEGER NOT NULL, n_samples INTEGER NOT NULL); 4 | INSERT INTO sphere_sample 5 | WITH square_sample AS (SELECT 2.0*(RANDOM() - 0.5) AS a1, 2.0*(RANDOM() - 0.5) AS b1, 2.0*(RANDOM() - 0.5) AS c1 6 | FROM generate_series(1, 5000)), 7 | ball_sample AS (SELECT a1 AS a, b1 AS b, c1 AS c, SQRT(a1*a1+b1*b1+c1*c1) AS radius FROM square_sample WHERE 1>=(a1*a1+b1*b1+c1*c1)), 8 | sphere_sample AS (SELECT a/radius AS x, b/radius AS y, c/radius AS z, a, b, c, ROW_NUMBER() OVER () AS sampleno, COUNT(*) OVER () AS n_samples FROM ball_sample) 9 | SELECT x,y,z,a,b,c,sampleno,n_samples FROM sphere_sample; 10 | DROP INDEX IF EXISTS idx_ss; 11 | CREATE INDEX IF NOT EXISTS idx_ss ON sphere_sample(sampleno); 12 | 13 | DROP VIEW IF EXISTS rays CASCADE; 14 | CREATE VIEW rays AS 15 | WITH RECURSIVE 16 | xs AS (SELECT 0 AS u, 0.0 AS img_frac_x UNION ALL SELECT u+1, (u+1.0)/img.res_x FROM xs, img WHERE xs.u0 THEN (CASE 52 | WHEN shade_normal THEN mat_col_r*(1+norm_x)/2 53 | ELSE mat_col_r 54 | END) 55 | ELSE 1.0-(0.5*((dir_y/SQRT(dir_lensquared)+1.0)))+0.2*(0.5*((dir_y/SQRT(dir_lensquared)+1.0))) END, 56 | CASE WHEN discrim>0 THEN (CASE 57 | WHEN shade_normal THEN mat_col_g*(1+norm_y)/2 58 | ELSE mat_col_g 59 | END) 60 | ELSE 1.0-(0.5*((dir_y/SQRT(dir_lensquared)+1.0)))+0.3*(0.5*((dir_y/SQRT(dir_lensquared)+1.0))) END, 61 | CASE WHEN discrim>0 THEN (CASE 62 | WHEN shade_normal THEN mat_col_b*(1+norm_z)/2 63 | ELSE mat_col_b 64 | END) 65 | ELSE 1.0-(0.5*((dir_y/SQRT(dir_lensquared)+1.0)))+1.0*(0.5*((dir_y/SQRT(dir_lensquared)+1.0))) END, 66 | -- x1, y1, z1 67 | hit_x, hit_y, hit_z, 68 | -- dir_x, dir_y, dir_z 69 | CASE WHEN is_metal OR (is_dielectric AND must_reflect) 70 | THEN (dir_x - 2 * norm_x * dot_ray_norm) / reflection_len 71 | WHEN is_dielectric THEN (reflec_dir_x + refrac_dir_x) / refrac_len 72 | ELSE diffuse_dir_x/diffuse_dir_len 73 | END, 74 | CASE WHEN is_metal OR (is_dielectric AND must_reflect) 75 | THEN (dir_y - 2 * norm_y * dot_ray_norm) / reflection_len 76 | WHEN is_dielectric THEN (reflec_dir_y + refrac_dir_y) / refrac_len 77 | ELSE diffuse_dir_y/diffuse_dir_len 78 | END, 79 | CASE WHEN is_metal OR (is_dielectric AND must_reflect) 80 | THEN (dir_z - 2 * norm_z * dot_ray_norm) / reflection_len 81 | WHEN is_dielectric THEN (reflec_dir_z + refrac_dir_z) / refrac_len 82 | ELSE diffuse_dir_z/diffuse_dir_len 83 | END, 84 | 1.0, 85 | norm_x, norm_y, norm_z, 1.0, 86 | discrim IS NULL, ROW_NUMBER() OVER (PARTITION BY img_x, img_y, depth+1, px_sample_n 87 | ORDER BY t), 88 | sphereid, n_sphere_samples, (inside_dielectric AND NOT must_reflect) OR (NOT inside_dielectric AND NOT is_dielectric) 89 | FROM rs 90 | LEFT JOIN LATERAL 91 | (SELECT s.*, (((x1-cx)*dir_x+(y1-cy)*dir_y+(z1-cz)*dir_z)*((x1-cx)*dir_x+(y1-cy)*dir_y+(z1-cz)*dir_z)- 92 | (((x1-cx)*(x1-cx)+(y1-cy)*(y1-cy)+(z1-cz)*(z1-cz)-radius2)*dir_lensquared)) discrim, 93 | (-((x1-cx)*dir_x+(y1-cy)*dir_y+(z1-cz)*dir_z) 94 | -SQRT(((x1-cx)*dir_x+(y1-cy)*dir_y+(z1-cz)*dir_z)*((x1-cx)*dir_x+(y1-cy)*dir_y+(z1-cz)*dir_z)- 95 | (((x1-cx)*(x1-cx)+(y1-cy)*(y1-cy)+(z1-cz)*(z1-cz)-radius2)*dir_lensquared))/dir_lensquared) t 96 | FROM sphere s 97 | WHERE s.sceneid=rs.sceneid 98 | ) hit_sphere ON discrim>0 AND t>0 99 | LEFT JOIN LATERAL 100 | (SELECT x1+dir_x*t AS hit_x, y1+dir_y*t AS hit_y, z1+dir_z*t AS hit_z, 101 | x1+dir_x*t-cx AS norm_x_nonunit, y1+dir_y*t-cy AS norm_y_nonunit, z1+dir_z*t-cz AS norm_z_nonunit, 102 | SQRT((x1+dir_x*t-cx)*(x1+dir_x*t-cx)+(y1+dir_y*t-cy)*(y1+dir_y*t-cy)+(z1+dir_z*t-cz)*(z1+dir_z*t-cz)) AS norm_len, 103 | ROW_NUMBER() OVER (PARTITION BY img_x, img_y, depth, px_sample_n ORDER BY t ASC) AS t_idx 104 | WHERE t>0 105 | ) sphere_normal ON t_idx=1 106 | LEFT JOIN LATERAL 107 | (SELECT norm_x_nonunit/norm_len AS norm_x, norm_y_nonunit/norm_len AS norm_y, norm_z_nonunit/norm_len AS norm_z 108 | ) sphere_unit_normal ON norm_x IS NOT NULL 109 | LEFT JOIN LATERAL 110 | (SELECT dir_x*norm_x + dir_y*norm_y + dir_z*norm_z AS dot_ray_norm, 111 | SQRT((dir_x - 2 * norm_x * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z)) * (dir_x - 2 * norm_x * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z)) + 112 | (dir_y - 2 * norm_y * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z)) * (dir_y - 2 * norm_y * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z)) + 113 | (dir_z - 2 * norm_z * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z)) * (dir_z - 2 * norm_z * (dir_x*norm_x + dir_y*norm_y + dir_z*norm_z))) AS reflection_len 114 | ) dot_ray_norm ON norm_x IS NOT NULL 115 | LEFT JOIN material ON material.materialid=hit_sphere.materialid 116 | LEFT JOIN LATERAL 117 | (SELECT x, y, z, 118 | x+norm_x AS diffuse_dir_x, y+norm_y AS diffuse_dir_y, z+norm_z AS diffuse_dir_z, 119 | SQRT((x+norm_x)*(x+norm_x)+(y+norm_y)*(y+norm_y)+(z+norm_z)*(z+norm_z)) AS diffuse_dir_len 120 | FROM sphere_sample ss WHERE ss.sampleno=1+CAST(FLOOR(ABS((100000*dir_x)-FLOOR(100000*dir_x))*n_sphere_samples) AS INTEGER) 121 | ) diffuse_scatter ON norm_x IS NOT NULL 122 | LEFT JOIN LATERAL 123 | (SELECT (CASE WHEN is_dielectric THEN 1.0/eta ELSE eta END) AS ir) index_of_refraction ON norm_x IS NOT NULL 124 | LEFT JOIN LATERAL 125 | (SELECT LEAST(1.0, (-(dir_x*norm_x) -(dir_y*norm_y) -(dir_z*norm_z))) AS cos_theta, 126 | ((1.0-ir)/(1.0+ir))*((1.0-ir)/(1.0+ir)) AS r0 127 | ) refract_cos_theta ON norm_x IS NOT NULL 128 | LEFT JOIN LATERAL 129 | (SELECT ir * (dir_x + cos_theta * norm_x) AS refrac_dir_x, 130 | ir * (dir_y + cos_theta * norm_y) AS refrac_dir_y, 131 | ir * (dir_z + cos_theta * norm_z) AS refrac_dir_z, 132 | SQRT(1.0-cos_theta*cos_theta) AS sin_theta, 133 | r0 + (1.0 - r0)*pow(1.0-cos_theta, 5) AS reflectance 134 | ) refrac_vec ON norm_x IS NOT NULL 135 | LEFT JOIN LATERAL 136 | (SELECT -norm_x*SQRT(ABS(1.0 - (refrac_dir_x*refrac_dir_x + refrac_dir_y*refrac_dir_y + refrac_dir_z*refrac_dir_z))) AS reflec_dir_x, 137 | -norm_y*SQRT(ABS(1.0 - (refrac_dir_x*refrac_dir_x + refrac_dir_y*refrac_dir_y + refrac_dir_z*refrac_dir_z))) AS reflec_dir_y, 138 | -norm_z*SQRT(ABS(1.0 - (refrac_dir_x*refrac_dir_x + refrac_dir_y*refrac_dir_y + refrac_dir_z*refrac_dir_z))) AS reflec_dir_z, 139 | (sin_theta*ir>1.0) OR (reflectance > RANDOM()) AS must_reflect 140 | ) reflec_vec ON norm_x IS NOT NULL 141 | LEFT JOIN LATERAL 142 | (SELECT SQRT((reflec_dir_x+refrac_dir_x)*(reflec_dir_x+refrac_dir_x)+ 143 | (reflec_dir_y+refrac_dir_y)*(reflec_dir_y+refrac_dir_y)+ 144 | (reflec_dir_z+refrac_dir_z)*(reflec_dir_z+refrac_dir_z)) refrac_len 145 | ) refrac_len ON norm_x IS NOT NULL 146 | WHERE depth=0 159 | GROUP BY -A.img_y, A.img_x 160 | ORDER BY -A.img_y, A.img_x; 161 | 162 | DROP VIEW IF EXISTS ppm; 163 | CREATE VIEW ppm AS 164 | WITH maxcol(mc) AS (SELECT 255) 165 | SELECT 'P3' 166 | UNION ALL 167 | SELECT res_x || ' ' || res_y || ' ' || mc FROM img, maxcol 168 | UNION ALL 169 | SELECT CAST(col_r*mc AS INTEGER) || ' ' || CAST(col_g*mc AS INTEGER) || ' ' || CAST(col_b*mc AS INTEGER) 170 | FROM do_render, maxcol; 171 | ; 172 | 173 | -- SELECT * FROM rays WHERE img_x=2 AND img_y=2; 174 | -------------------------------------------------------------------------------- /setup.sql: -------------------------------------------------------------------------------- 1 | DROP TABLE IF EXISTS material CASCADE; 2 | CREATE TABLE material (materialid SERIAL PRIMARY KEY, name TEXT, 3 | mat_col_r DOUBLE PRECISION, mat_col_g DOUBLE PRECISION, mat_col_b DOUBLE PRECISION, 4 | is_metal BOOLEAN NOT NULL, shade_normal BOOLEAN NOT NULL, mirror_frac DOUBLE PRECISION NOT NULL, 5 | is_dielectric BOOLEAN NOT NULL, eta DOUBLE PRECISION NOT NULL DEFAULT 1.0); 6 | INSERT INTO material (name, mat_col_r, mat_col_g, mat_col_b, is_metal, shade_normal, mirror_frac, is_dielectric, eta) VALUES 7 | ('dark', 0.1, 0.1, 0.1, FALSE, FALSE, 0.1, FALSE, 1.0), 8 | ('red', 0.95, 0.0, 0.0, FALSE, TRUE, 0.5, FALSE, 1.0), 9 | ('green', 0.0, 0.95, 0.0, FALSE, TRUE, 0.5, FALSE, 1.0), 10 | ('blue', 0.0, 0.0, 0.95, TRUE, TRUE, 0.5, FALSE, 1.0), 11 | ('grey', 0.1, 0.1, 0.1, FALSE, FALSE, 0.5, FALSE, 1.0), 12 | ('bright', 1.0, 1.0, 1.0, TRUE, TRUE, 0.5, FALSE, 1.0), 13 | ('mirror', NULL, NULL, NULL, TRUE, FALSE, 0.99, FALSE, 1.0), 14 | ('bluemirror', 0.0, 0.0, 0.3, TRUE, FALSE, 0.9, FALSE, 1.0), 15 | ('greenmirror', 0.0, 0.2, 0.0, TRUE, FALSE, 0.9, FALSE, 1.0), 16 | ('glass', NULL, NULL, NULL, FALSE, FALSE, 0.95, TRUE, 1.5), 17 | ('greenglass', 0.0, 0.2, 0.0, FALSE, FALSE, 0.8, TRUE, 1.5), 18 | ('diamond', NULL, NULL, NULL, FALSE, FALSE, 0.99, TRUE, 2.4), 19 | ('antiglass', NULL, NULL, NULL, FALSE, FALSE, 0.99, TRUE, 0.2) 20 | ; 21 | 22 | DROP TABLE IF EXISTS scene CASCADE; 23 | CREATE TABLE IF NOT EXISTS scene (sceneid SERIAL PRIMARY KEY, 24 | scenename TEXT UNIQUE NOT NULL); 25 | INSERT INTO scene (scenename) VALUES ('dielectricparty'), 26 | ('oneglassball'), 27 | ('onediamondball'), 28 | ('oneantiglassball'), 29 | ('onegreyball'), 30 | ('onegreenball'), 31 | ('twomirrorballs'), 32 | ('twodiffuseballs'), 33 | ('onemirrorball'), 34 | ('reflectiontest'), 35 | ('threemirrors'), 36 | ('adjacentballs'), 37 | ('busyday'); 38 | 39 | DROP TABLE IF EXISTS sphere CASCADE; 40 | CREATE TABLE sphere (sphereid SERIAL, sceneid INTEGER NOT NULL REFERENCES scene(sceneid), 41 | cx DOUBLE PRECISION NOT NULL, cy DOUBLE PRECISION NOT NULL, cz DOUBLE PRECISION NOT NULL, 42 | radius DOUBLE PRECISION, radius2 DOUBLE PRECISION, materialid INTEGER NOT NULL REFERENCES material(materialid) DEFERRABLE, 43 | vel_x DOUBLE PRECISION NOT NULL DEFAULT 0.0, vel_y DOUBLE PRECISION NOT NULL DEFAULT 0.0, vel_z DOUBLE PRECISION NOT NULL DEFAULT 0.0, 44 | coefficient_of_restitution DOUBLE PRECISION NOT NULL DEFAULT 1.0); 45 | 46 | INSERT INTO sphere (cx, cy, cz, radius, materialid, sceneid) VALUES 47 | (0, 24, -10, 5, 48 | (SELECT materialid FROM material WHERE name='bright'), (SELECT sceneid FROM scene WHERE scenename='reflectiontest')), 49 | (0, 5, 0, 5, 50 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='reflectiontest')), 51 | (-17, 15, -30, 15, 52 | (SELECT materialid FROM material WHERE name='bluemirror'), (SELECT sceneid FROM scene WHERE scenename='reflectiontest')), 53 | (24, 23, 10, 23, 54 | (SELECT materialid FROM material WHERE name='greenmirror'), (SELECT sceneid FROM scene WHERE scenename='reflectiontest')), 55 | 56 | (0, -1250, 0, 1250, 57 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='twomirrorballs')), 58 | (20, 25, -30, 25, 59 | (SELECT materialid FROM material WHERE name='greenmirror'), (SELECT sceneid FROM scene WHERE scenename='twomirrorballs')), 60 | (-20, 25, 0, 25, 61 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='twomirrorballs')), 62 | 63 | (0, -1250, 0, 1250, 64 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='twodiffuseballs')), 65 | (20, 25, -30, 25, 66 | (SELECT materialid FROM material WHERE name='dark'), (SELECT sceneid FROM scene WHERE scenename='twodiffuseballs')), 67 | (-20, 25, 0, 25, 68 | (SELECT materialid FROM material WHERE name='green'), (SELECT sceneid FROM scene WHERE scenename='twodiffuseballs')), 69 | 70 | (0, -1250, 0, 1250, 71 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='onemirrorball')), 72 | (-20, 25, 0, 25, 73 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='onemirrorball')), 74 | 75 | (0, -1250, 0, 1250, 76 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='oneglassball')), 77 | (0, 25, -10, 25, 78 | (SELECT materialid FROM material WHERE name='glass'), (SELECT sceneid FROM scene WHERE scenename='oneglassball')), 79 | (10, 25, 40, 25, 80 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='oneglassball')), 81 | 82 | (0, -1250, 0, 1250, 83 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='onediamondball')), 84 | (0, 25, -10, 25, 85 | (SELECT materialid FROM material WHERE name='diamond'), (SELECT sceneid FROM scene WHERE scenename='onediamondball')), 86 | (10, 25, 40, 25, 87 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='onediamondball')), 88 | 89 | (0, -1250, 0, 1250, 90 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='oneantiglassball')), 91 | (0, 25, -10, 25, 92 | (SELECT materialid FROM material WHERE name='antiglass'), (SELECT sceneid FROM scene WHERE scenename='oneantiglassball')), 93 | (10, 25, 40, 25, 94 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='oneantiglassball')), 95 | 96 | (0, -1250, 0, 1250, 97 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 98 | (0, 12, 0, NULL, 99 | (SELECT materialid FROM material WHERE name='glass'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 100 | (25, 12, 0, NULL, 101 | (SELECT materialid FROM material WHERE name='antiglass'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 102 | (-25, 12, 0, NULL, 103 | (SELECT materialid FROM material WHERE name='diamond'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 104 | (15, 10, 20, NULL, 105 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 106 | (-5, 10, 30, NULL, 107 | (SELECT materialid FROM material WHERE name='green'), (SELECT sceneid FROM scene WHERE scenename='dielectricparty')), 108 | 109 | (0, -1250, 0, 1250, 110 | (SELECT materialid FROM material WHERE name='green'), (SELECT sceneid FROM scene WHERE scenename='adjacentballs')), 111 | (-24, 12, 0, 12, 112 | (SELECT materialid FROM material WHERE name='red'), (SELECT sceneid FROM scene WHERE scenename='adjacentballs')), 113 | (0, 12, 0, 12, 114 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='adjacentballs')), 115 | (24, 12, 0, 12, 116 | (SELECT materialid FROM material WHERE name='bright'), (SELECT sceneid FROM scene WHERE scenename='adjacentballs')), 117 | 118 | (0, -1250, 0, 1250, 119 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='onegreyball')), 120 | (20, 25, 0, 25, 121 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='onegreyball')), 122 | 123 | (0, -1250, 0, 1250, 124 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='onegreenball')), 125 | (20, 25, 0, 25, 126 | (SELECT materialid FROM material WHERE name='green'), (SELECT sceneid FROM scene WHERE scenename='onegreenball')), 127 | 128 | (-20, 15, -15, 22, 129 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='threemirrors')), 130 | (0, 0, 0, 5, 131 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='threemirrors')), 132 | (30, -15, 0, 25, 133 | (SELECT materialid FROM material WHERE name='mirror'), (SELECT sceneid FROM scene WHERE scenename='threemirrors')), 134 | 135 | (0, -1250, 0, 1250, 136 | (SELECT materialid FROM material WHERE name='grey'), (SELECT sceneid FROM scene WHERE scenename='busyday')) 137 | ; 138 | INSERT INTO sphere (cx, cy, cz, radius, materialid, sceneid, coefficient_of_restitution) 139 | SELECT (RANDOM()-0.5) * 100, 50 + RANDOM() * 20, (RANDOM()-0.5) * 100, RANDOM() * 15, 140 | 1+CAST((RANDOM()*(SELECT MAX(materialid)-1 FROM material)) AS INTEGER), (SELECT sceneid FROM scene WHERE scenename='busyday'), 141 | 0.5*RANDOM()+0.5 142 | FROM generate_series(1, 30) 143 | GROUP BY generate_series; 144 | 145 | UPDATE sphere SET radius = cy WHERE radius IS NULL; 146 | UPDATE sphere SET radius2 = radius*radius WHERE radius2 IS NULL; 147 | 148 | DROP TABLE IF EXISTS camera CASCADE; 149 | CREATE TABLE camera (cameraid INTEGER PRIMARY KEY, sceneid INTEGER NOT NULL REFERENCES scene(sceneid), 150 | x DOUBLE PRECISION NOT NULL, y DOUBLE PRECISION NOT NULL, z DOUBLE PRECISION NOT NULL, 151 | rot_x DOUBLE PRECISION NOT NULL, rot_y DOUBLE PRECISION NOT NULL, rot_z DOUBLE PRECISION NOT NULL, 152 | fov_rad_x DOUBLE PRECISION NOT NULL, fov_rad_y DOUBLE PRECISION NOT NULL, 153 | max_ray_depth INTEGER NOT NULL, samples_per_px INTEGER NOT NULL); 154 | INSERT INTO camera (cameraid, x, y, z, rot_x, rot_y, rot_z, fov_rad_x, fov_rad_y, max_ray_depth, samples_per_px, sceneid) 155 | VALUES (1.0, 0.0, 65.0, -120.0, -0.34, 0.0, 0.0, PI()/3.0, PI()/3.0, 156 | 40, 30, (SELECT sceneid FROM scene WHERE scenename='busyday')); 157 | 158 | DROP TABLE IF EXISTS img CASCADE; 159 | CREATE TABLE img (res_x INTEGER NOT NULL, res_y INTEGER NOT NULL, gamma DOUBLE PRECISION); 160 | INSERT INTO img (res_x, res_y, gamma) 161 | VALUES (650, 650, 1.0); 162 | 163 | CREATE OR REPLACE FUNCTION animate_spheres() 164 | RETURNS TRIGGER 165 | LANGUAGE PLPGSQL 166 | AS $$ 167 | BEGIN 168 | UPDATE sphere SET vel_x = vel_x + NEW.grav_x*NEW.dt, 169 | vel_y = vel_y + NEW.grav_y*NEW.dt, 170 | vel_z = vel_z + NEW.grav_z*NEW.dt 171 | WHERE sceneid=(SELECT sceneid FROM camera) AND cy>0; 172 | UPDATE sphere SET vel_y = -vel_y*coefficient_of_restitution WHERE radius>cy 173 | AND sceneid=(SELECT sceneid FROM camera); 174 | UPDATE sphere SET cx=cx+vel_x*NEW.dt, 175 | cy=cy+vel_y*NEW.dt, 176 | cz=cz+vel_z*NEW.dt 177 | WHERE sceneid=(SELECT sceneid FROM camera); 178 | RETURN NEW; 179 | END; 180 | $$ ; 181 | 182 | DROP VIEW IF EXISTS updateworld; 183 | CREATE VIEW updateworld AS (SELECT 0.0 AS dt, 0.0 AS grav_x, 0.0 AS grav_y, 0.0 AS grav_z); 184 | CREATE TRIGGER trig_update_world INSTEAD OF INSERT ON updateworld FOR EACH ROW 185 | EXECUTE PROCEDURE animate_spheres(); 186 | 187 | -- INSERT INTO updateworld (dt, grav_x, grav_y, grav_z) VALUES (0.1, 0.0, -9.8, 0.0); 188 | -- select cx, cy, cz, vel_x, vel_y, vel_z from sphere 189 | -- where sceneid=(SELECT sceneid FROM scene WHERE scenename='busyday'); --------------------------------------------------------------------------------